1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := public.gettokenstring(public.transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
259 CREATE OR REPLACE FUNCTION reverse_place_diameter(rank_search SMALLINT)
263 IF rank_search <= 4 THEN
265 ELSIF rank_search <= 8 THEN
267 ELSIF rank_search <= 12 THEN
269 ELSIF rank_search <= 17 THEN
271 ELSIF rank_search <= 18 THEN
273 ELSIF rank_search <= 19 THEN
280 LANGUAGE plpgsql IMMUTABLE;
282 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
283 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
290 postcode := upper(postcode);
292 IF country_code = 'gb' THEN
293 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
296 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
299 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
304 ELSEIF country_code = 'sg' THEN
305 IF postcode ~ '^([0-9]{6})$' THEN
310 ELSEIF country_code = 'de' THEN
311 IF postcode ~ '^([0-9]{5})$' THEN
317 -- Guess at the postcode format and coverage (!)
318 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
322 -- Does it look splitable into and area and local code?
323 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
325 IF part IS NOT NULL THEN
328 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
337 LANGUAGE plpgsql IMMUTABLE;
339 -- Find the nearest artificial postcode for the given geometry.
340 -- TODO For areas there should not be more than two inside the geometry.
341 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
347 -- If the geometry is an area then only one postcode must be within
348 -- that area, otherwise consider the area as not having a postcode.
349 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
350 SELECT min(postcode), count(*) FROM
351 (SELECT postcode FROM location_postcode
352 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
362 SELECT postcode FROM location_postcode
363 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
364 AND location_postcode.country_code = country
365 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
374 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
383 FOR item IN SELECT (each(src)).* LOOP
385 s := make_standard_name(item.value);
386 w := getorcreate_country(s, lookup_country_code);
388 words := regexp_split_to_array(item.value, E'[,;()]');
389 IF array_upper(words, 1) != 1 THEN
390 FOR j IN 1..array_upper(words, 1) LOOP
391 s := make_standard_name(words[j]);
393 w := getorcreate_country(s, lookup_country_code);
402 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
412 result := '{}'::INTEGER[];
414 FOR item IN SELECT (each(src)).* LOOP
416 s := make_standard_name(item.value);
418 w := getorcreate_name_id(s, item.value);
420 IF not(ARRAY[w] <@ result) THEN
421 result := result || w;
424 w := getorcreate_word_id(s);
426 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 words := string_to_array(s, ' ');
431 IF array_upper(words, 1) IS NOT NULL THEN
432 FOR j IN 1..array_upper(words, 1) LOOP
433 IF (words[j] != '') THEN
434 w = getorcreate_word_id(words[j]);
435 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
436 result := result || w;
442 words := regexp_split_to_array(item.value, E'[,;()]');
443 IF array_upper(words, 1) != 1 THEN
444 FOR j IN 1..array_upper(words, 1) LOOP
445 s := make_standard_name(words[j]);
447 w := getorcreate_word_id(s);
448 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
449 result := result || w;
455 s := regexp_replace(item.value, '市$', '');
456 IF s != item.value THEN
457 s := make_standard_name(s);
459 w := getorcreate_name_id(s, item.value);
460 IF NOT (ARRAY[w] <@ result) THEN
461 result := result || w;
471 LANGUAGE plpgsql IMMUTABLE;
473 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
483 result := '{}'::INTEGER[];
485 s := make_standard_name(src);
486 w := getorcreate_name_id(s, src);
488 IF NOT (ARRAY[w] <@ result) THEN
489 result := result || w;
492 w := getorcreate_word_id(s);
494 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
495 result := result || w;
498 words := string_to_array(s, ' ');
499 IF array_upper(words, 1) IS NOT NULL THEN
500 FOR j IN 1..array_upper(words, 1) LOOP
501 IF (words[j] != '') THEN
502 w = getorcreate_word_id(words[j]);
503 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
504 result := result || w;
510 words := regexp_split_to_array(src, E'[,;()]');
511 IF array_upper(words, 1) != 1 THEN
512 FOR j IN 1..array_upper(words, 1) LOOP
513 s := make_standard_name(words[j]);
515 w := getorcreate_word_id(s);
516 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
517 result := result || w;
523 s := regexp_replace(src, '市$', '');
525 s := make_standard_name(s);
527 w := getorcreate_name_id(s, src);
528 IF NOT (ARRAY[w] <@ result) THEN
529 result := result || w;
537 LANGUAGE plpgsql IMMUTABLE;
539 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
542 place_centre GEOMETRY;
545 place_centre := ST_PointOnSurface(place);
547 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
549 -- Try for a OSM polygon
550 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
552 RETURN nearcountry.country_code;
555 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
557 -- Try for OSM fallback data
558 -- The order is to deal with places like HongKong that are 'states' within another polygon
559 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
561 RETURN nearcountry.country_code;
564 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
566 -- Natural earth data
567 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
569 RETURN nearcountry.country_code;
572 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
575 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
577 RETURN nearcountry.country_code;
580 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
582 -- Natural earth data
583 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
585 RETURN nearcountry.country_code;
591 LANGUAGE plpgsql IMMUTABLE;
593 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
598 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
600 RETURN lower(nearcountry.country_default_language_code);
605 LANGUAGE plpgsql IMMUTABLE;
607 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
612 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
614 RETURN lower(nearcountry.country_default_language_codes);
619 LANGUAGE plpgsql IMMUTABLE;
621 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
626 FOR nearcountry IN select partition from country_name where country_code = in_country_code
628 RETURN nearcountry.partition;
633 LANGUAGE plpgsql IMMUTABLE;
635 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
639 DELETE FROM location_area where place_id = OLD_place_id;
640 -- TODO:location_area
646 CREATE OR REPLACE FUNCTION add_location(
648 country_code varchar(2),
652 rank_address INTEGER,
668 IF rank_search > 25 THEN
669 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
672 x := deleteLocationArea(partition, place_id, rank_search);
674 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
676 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
677 postcode := upper(trim (in_postcode));
680 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
681 centroid := ST_Centroid(geometry);
683 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
684 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
690 IF rank_address = 0 THEN
692 ELSEIF rank_search <= 14 THEN
694 ELSEIF rank_search <= 15 THEN
696 ELSEIF rank_search <= 16 THEN
698 ELSEIF rank_search <= 17 THEN
700 ELSEIF rank_search <= 21 THEN
702 ELSEIF rank_search = 25 THEN
706 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
708 secgeo := ST_Buffer(geometry, diameter);
709 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
719 -- find the parent road of the cut road parts
720 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
721 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
726 parent_place_id BIGINT;
727 address_street_word_ids INTEGER[];
733 addr_street = street;
736 IF addr_street is null and addr_place is null THEN
737 select nodes from planet_osm_ways where id = wayid INTO waynodes;
738 FOR location IN SELECT placex.address from placex
739 where osm_type = 'N' and osm_id = ANY(waynodes)
740 and placex.address is not null
741 and (placex.address ? 'street' or placex.address ? 'place')
742 and indexed_status < 100
744 addr_street = location.address->'street';
745 addr_place = location.address->'place';
749 IF addr_street IS NOT NULL THEN
750 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
751 IF address_street_word_ids IS NOT NULL THEN
752 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
753 parent_place_id := location.place_id;
758 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
759 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
760 IF address_street_word_ids IS NOT NULL THEN
761 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
762 parent_place_id := location.place_id;
767 IF parent_place_id is null THEN
768 FOR location IN SELECT place_id FROM placex
769 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
770 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
771 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
772 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
774 parent_place_id := location.place_id;
778 IF parent_place_id is null THEN
782 RETURN parent_place_id;
788 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
791 NEW.place_id := nextval('seq_place');
792 NEW.indexed_date := now();
794 IF NEW.indexed_status IS NULL THEN
795 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
796 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
797 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
801 NEW.indexed_status := 1; --STATUS_NEW
802 NEW.country_code := lower(get_country_code(NEW.linegeo));
804 NEW.partition := get_partition(NEW.country_code);
805 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
814 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
820 country_code VARCHAR(2);
821 default_language VARCHAR(10);
826 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
828 NEW.place_id := nextval('seq_place');
829 NEW.indexed_status := 1; --STATUS_NEW
831 NEW.country_code := lower(get_country_code(NEW.geometry));
833 NEW.partition := get_partition(NEW.country_code);
834 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
836 -- copy 'name' to or from the default language (if there is a default language)
837 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
838 default_language := get_country_language_code(NEW.country_code);
839 IF default_language IS NOT NULL THEN
840 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
841 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
842 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
843 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
848 IF NEW.osm_type = 'X' THEN
849 -- E'X'ternal records should already be in the right format so do nothing
851 NEW.rank_search := 30;
852 NEW.rank_address := NEW.rank_search;
854 -- By doing in postgres we have the country available to us - currently only used for postcode
855 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
857 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
858 -- most likely just a part of a multipolygon postcode boundary, throw it away
862 NEW.name := hstore('ref', NEW.address->'postcode');
864 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
865 INTO NEW.rank_search, NEW.rank_address;
867 IF NOT ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon') THEN
868 NEW.rank_address := 0;
871 ELSEIF NEW.class = 'place' THEN
872 IF NEW.type in ('continent') THEN
873 NEW.rank_search := 2;
874 NEW.rank_address := NEW.rank_search;
875 NEW.country_code := NULL;
876 ELSEIF NEW.type in ('sea') THEN
877 NEW.rank_search := 2;
878 NEW.rank_address := 0;
879 NEW.country_code := NULL;
880 ELSEIF NEW.type in ('country') THEN
881 NEW.rank_search := 4;
882 NEW.rank_address := NEW.rank_search;
883 ELSEIF NEW.type in ('state') THEN
884 NEW.rank_search := 8;
885 NEW.rank_address := NEW.rank_search;
886 ELSEIF NEW.type in ('region') THEN
887 NEW.rank_search := 18; -- dropped from previous value of 10
888 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
889 ELSEIF NEW.type in ('county') THEN
890 NEW.rank_search := 12;
891 NEW.rank_address := NEW.rank_search;
892 ELSEIF NEW.type in ('city') THEN
893 NEW.rank_search := 16;
894 NEW.rank_address := NEW.rank_search;
895 ELSEIF NEW.type in ('island') THEN
896 NEW.rank_search := 17;
897 NEW.rank_address := 0;
898 ELSEIF NEW.type in ('town') THEN
899 NEW.rank_search := 18;
900 NEW.rank_address := 16;
901 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
902 NEW.rank_search := 19;
903 NEW.rank_address := 16;
904 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
905 NEW.rank_search := 20;
906 NEW.rank_address := NEW.rank_search;
907 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
908 NEW.rank_search := 20;
909 NEW.rank_address := 0;
910 -- Irish townlands, tagged as place=locality and locality=townland
911 IF (NEW.extratags -> 'locality') = 'townland' THEN
912 NEW.rank_address := 20;
914 ELSEIF NEW.type in ('neighbourhood') THEN
915 NEW.rank_search := 22;
916 NEW.rank_address := 22;
917 ELSEIF NEW.type in ('house','building') THEN
918 NEW.rank_search := 30;
919 NEW.rank_address := NEW.rank_search;
920 ELSEIF NEW.type in ('houses') THEN
921 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
922 NEW.rank_search := 28;
923 NEW.rank_address := 0;
926 ELSEIF NEW.class = 'boundary' THEN
927 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
928 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
931 NEW.rank_search := NEW.admin_level * 2;
932 IF NEW.type = 'administrative' THEN
933 NEW.rank_address := NEW.rank_search;
935 NEW.rank_address := 0;
937 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
938 NEW.rank_search := 22;
939 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
940 NEW.rank_address := NEW.rank_search;
942 NEW.rank_address := 0;
944 ELSEIF NEW.class = 'leisure' and NEW.type in ('park') THEN
945 NEW.rank_search := 24;
946 NEW.rank_address := 0;
947 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
948 NEW.rank_search := 18;
949 NEW.rank_address := 0;
950 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
951 NEW.rank_search := 4;
952 NEW.rank_address := NEW.rank_search;
953 -- any feature more than 5 square miles is probably worth indexing
954 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
955 NEW.rank_search := 22;
956 NEW.rank_address := 0;
957 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
959 ELSEIF NEW.class = 'waterway' THEN
960 IF NEW.osm_type = 'R' THEN
961 NEW.rank_search := 16;
963 NEW.rank_search := 17;
965 NEW.rank_address := 0;
966 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
967 NEW.rank_search := 27;
968 NEW.rank_address := NEW.rank_search;
969 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
970 NEW.rank_search := 26;
971 NEW.rank_address := NEW.rank_search;
972 ELSEIF NEW.class = 'mountain_pass' THEN
973 NEW.rank_search := 20;
974 NEW.rank_address := 0;
979 IF NEW.rank_search > 30 THEN
980 NEW.rank_search := 30;
983 IF NEW.rank_address > 30 THEN
984 NEW.rank_address := 30;
987 IF (NEW.extratags -> 'capital') = 'yes' THEN
988 NEW.rank_search := NEW.rank_search - 1;
991 -- a country code make no sense below rank 4 (country)
992 IF NEW.rank_search < 4 THEN
993 NEW.country_code := NULL;
996 -- Block import below rank 22
997 -- IF NEW.rank_search > 22 THEN
1001 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1003 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
1005 IF NEW.rank_address > 0 THEN
1006 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1007 -- Performance: We just can't handle re-indexing for country level changes
1008 IF st_area(NEW.geometry) < 1 THEN
1009 -- mark items within the geometry for re-indexing
1010 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1012 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1013 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1014 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'));
1015 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1016 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'));
1019 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1021 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1022 IF NEW.type='postcode' THEN
1024 ELSEIF NEW.rank_search < 16 THEN
1026 ELSEIF NEW.rank_search < 18 THEN
1028 ELSEIF NEW.rank_search < 20 THEN
1030 ELSEIF NEW.rank_search = 21 THEN
1032 ELSEIF NEW.rank_search < 24 THEN
1034 ELSEIF NEW.rank_search < 26 THEN
1035 diameter := 0.002; -- 100 to 200 meters
1036 ELSEIF NEW.rank_search < 28 THEN
1037 diameter := 0.001; -- 50 to 100 meters
1039 IF diameter > 0 THEN
1040 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1041 IF NEW.rank_search >= 26 THEN
1042 -- roads may cause reparenting for >27 rank places
1043 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1044 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1045 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1046 ELSEIF NEW.rank_search >= 16 THEN
1047 -- up to rank 16, street-less addresses may need reparenting
1048 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');
1050 -- for all other places the search terms may change as well
1051 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);
1058 -- add to tables for special search
1059 -- Note: won't work on initial import because the classtype tables
1060 -- do not yet exist. It won't hurt either.
1061 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1062 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1064 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1065 USING NEW.place_id, ST_Centroid(NEW.geometry);
1074 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1078 place_centroid GEOMETRY;
1082 startnumber INTEGER;
1087 sectiongeo GEOMETRY;
1088 interpol_postcode TEXT;
1092 IF OLD.indexed_status = 100 THEN
1093 delete from location_property_osmline where place_id = OLD.place_id;
1097 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1101 NEW.interpolationtype = NEW.address->'interpolation';
1103 place_centroid := ST_PointOnSurface(NEW.linegeo);
1104 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1105 NEW.address->'place',
1106 NEW.partition, place_centroid, NEW.linegeo);
1108 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1109 interpol_postcode := NEW.address->'postcode';
1110 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1112 interpol_postcode := NULL;
1115 -- if the line was newly inserted, split the line as necessary
1116 IF OLD.indexed_status = 1 THEN
1117 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1119 IF array_upper(waynodes, 1) IS NULL THEN
1123 linegeo := NEW.linegeo;
1124 startnumber := NULL;
1126 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1128 select osm_id, address, geometry
1129 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1130 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1131 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1132 IF nextnode.osm_id IS NOT NULL THEN
1133 --RAISE NOTICE 'place_id is not null';
1134 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1135 -- Make sure that the point is actually on the line. That might
1136 -- be a bit paranoid but ensures that the algorithm still works
1137 -- should osm2pgsql attempt to repair geometries.
1138 splitline := split_line_on_node(linegeo, nextnode.geometry);
1139 sectiongeo := ST_GeometryN(splitline, 1);
1140 linegeo := ST_GeometryN(splitline, 2);
1142 sectiongeo = linegeo;
1144 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1146 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1147 AND startnumber != endnumber
1148 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1150 IF (startnumber > endnumber) THEN
1151 housenum := endnumber;
1152 endnumber := startnumber;
1153 startnumber := housenum;
1154 sectiongeo := ST_Reverse(sectiongeo);
1157 -- determine postcode
1158 postcode := coalesce(interpol_postcode,
1159 prevnode.address->'postcode',
1160 nextnode.address->'postcode',
1163 IF postcode is NULL THEN
1164 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1166 IF postcode is NULL THEN
1167 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1170 IF NEW.startnumber IS NULL THEN
1171 NEW.startnumber := startnumber;
1172 NEW.endnumber := endnumber;
1173 NEW.linegeo := sectiongeo;
1174 NEW.postcode := upper(trim(postcode));
1176 insert into location_property_osmline
1177 (linegeo, partition, osm_id, parent_place_id,
1178 startnumber, endnumber, interpolationtype,
1179 address, postcode, country_code,
1180 geometry_sector, indexed_status)
1181 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1182 startnumber, endnumber, NEW.interpolationtype,
1183 NEW.address, postcode,
1184 NEW.country_code, NEW.geometry_sector, 0);
1188 -- early break if we are out of line string,
1189 -- might happen when a line string loops back on itself
1190 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1194 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1195 prevnode := nextnode;
1200 -- marking descendants for reparenting is not needed, because there are
1201 -- actually no descendants for interpolation lines
1207 -- Trigger for updates of location_postcode
1209 -- Computes the parent object the postcode most likely refers to.
1210 -- This will be the place that determines the address displayed when
1211 -- searching for this postcode.
1212 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1219 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1223 NEW.indexed_date = now();
1225 partition := get_partition(NEW.country_code);
1227 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1228 INTO NEW.rank_search, NEW.rank_address;
1230 NEW.parent_place_id = 0;
1233 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1234 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1236 NEW.parent_place_id = location.place_id;
1244 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1249 place_centroid GEOMETRY;
1251 search_maxdistance FLOAT[];
1252 search_mindistance FLOAT[];
1253 address_havelevel BOOLEAN[];
1260 relation_members TEXT[];
1262 linkedplacex RECORD;
1264 search_diameter FLOAT;
1265 search_prevdiameter FLOAT;
1266 search_maxrank INTEGER;
1267 address_maxrank INTEGER;
1268 address_street_word_id INTEGER;
1269 address_street_word_ids INTEGER[];
1270 parent_place_id_rank BIGINT;
1278 location_rank_search INTEGER;
1279 location_distance FLOAT;
1280 location_parent GEOMETRY;
1281 location_isaddress BOOLEAN;
1282 location_keywords INTEGER[];
1284 default_language TEXT;
1285 name_vector INTEGER[];
1286 nameaddress_vector INTEGER[];
1288 linked_node_id BIGINT;
1289 linked_importance FLOAT;
1290 linked_wikipedia TEXT;
1295 IF OLD.indexed_status = 100 THEN
1296 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1297 delete from placex where place_id = OLD.place_id;
1301 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1305 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1307 NEW.indexed_date = now();
1309 result := deleteSearchName(NEW.partition, NEW.place_id);
1310 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1311 result := deleteRoad(NEW.partition, NEW.place_id);
1312 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1313 UPDATE placex set linked_place_id = null, indexed_status = 2
1314 where linked_place_id = NEW.place_id;
1315 -- update not necessary for osmline, cause linked_place_id does not exist
1317 IF NEW.linked_place_id is not null THEN
1318 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1322 --DEBUG: RAISE WARNING 'Copy over address tags';
1323 IF NEW.address is not NULL THEN
1324 IF NEW.address ? 'conscriptionnumber' THEN
1325 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1326 IF NEW.address ? 'streetnumber' THEN
1327 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1328 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1330 NEW.housenumber := NEW.address->'conscriptionnumber';
1332 ELSEIF NEW.address ? 'streetnumber' THEN
1333 NEW.housenumber := NEW.address->'streetnumber';
1334 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1335 ELSEIF NEW.address ? 'housenumber' THEN
1336 NEW.housenumber := NEW.address->'housenumber';
1337 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1340 addr_street := NEW.address->'street';
1341 addr_place := NEW.address->'place';
1343 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1344 i := getorcreate_postcode_id(NEW.address->'postcode');
1348 -- Speed up searches - just use the centroid of the feature
1349 -- cheaper but less acurate
1350 place_centroid := ST_PointOnSurface(NEW.geometry);
1351 NEW.centroid := null;
1352 NEW.postcode := null;
1353 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1355 -- recalculate country and partition
1356 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1357 -- for countries, believe the mapped country code,
1358 -- so that we remain in the right partition if the boundaries
1360 NEW.country_code := lower(NEW.address->'country');
1361 NEW.partition := get_partition(lower(NEW.country_code));
1362 IF NEW.partition = 0 THEN
1363 NEW.country_code := lower(get_country_code(place_centroid));
1364 NEW.partition := get_partition(NEW.country_code);
1367 IF NEW.rank_search >= 4 THEN
1368 NEW.country_code := lower(get_country_code(place_centroid));
1370 NEW.country_code := NULL;
1372 NEW.partition := get_partition(NEW.country_code);
1374 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1376 -- waterway ways are linked when they are part of a relation and have the same class/type
1377 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1378 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1380 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1381 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1382 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1383 FOR linked_node_id IN SELECT place_id FROM placex
1384 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1385 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1386 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1388 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1393 --DEBUG: RAISE WARNING 'Waterway processed';
1396 -- Adding ourselves to the list simplifies address calculations later
1397 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1398 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1400 -- What level are we searching from
1401 search_maxrank := NEW.rank_search;
1403 -- Thought this wasn't needed but when we add new languages to the country_name table
1404 -- we need to update the existing names
1405 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1406 default_language := get_country_language_code(NEW.country_code);
1407 IF default_language IS NOT NULL THEN
1408 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1409 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1410 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1411 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1415 --DEBUG: RAISE WARNING 'Local names updated';
1417 -- Initialise the name vector using our name
1418 name_vector := make_keywords(NEW.name);
1419 nameaddress_vector := '{}'::int[];
1422 address_havelevel[i] := false;
1425 NEW.importance := null;
1426 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1427 IF NEW.importance IS NULL THEN
1428 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;
1431 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1433 -- ---------------------------------------------------------------------------
1434 -- For low level elements we inherit from our parent road
1435 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1437 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1439 -- We won't get a better centroid, besides these places are too small to care
1440 NEW.centroid := place_centroid;
1442 NEW.parent_place_id := null;
1444 -- if we have a POI and there is no address information,
1445 -- see if we can get it from a surrounding building
1446 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1447 AND NEW.housenumber IS NULL THEN
1448 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1449 and address is not null
1450 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1451 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1454 NEW.housenumber := location.address->'housenumber';
1455 addr_street := location.address->'street';
1456 addr_place := location.address->'place';
1457 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1461 -- We have to find our parent road.
1462 -- Copy data from linked items (points on ways, addr:street links, relations)
1464 -- Is this object part of a relation?
1465 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1467 -- At the moment we only process one type of relation - associatedStreet
1468 IF relation.tags @> ARRAY['associatedStreet'] THEN
1469 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1470 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1471 --RAISE WARNING 'node in relation %',relation;
1472 SELECT place_id from placex where osm_type = 'W'
1473 and osm_id = substring(relation.members[i],2,200)::bigint
1474 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1479 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1481 -- Note that addr:street links can only be indexed once the street itself is indexed
1482 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1483 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1484 IF address_street_word_ids IS NOT NULL THEN
1485 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1488 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1490 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1491 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1492 IF address_street_word_ids IS NOT NULL THEN
1493 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1496 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1498 -- Is this node part of an interpolation?
1499 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1500 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1501 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1502 LIMIT 1 INTO NEW.parent_place_id;
1504 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1506 -- Is this node part of a way?
1507 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1510 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1511 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)
1513 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1515 -- Way IS a road then we are on it - that must be our road
1516 IF location.rank_search < 28 THEN
1517 --RAISE WARNING 'node in way that is a street %',location;
1518 NEW.parent_place_id := location.place_id;
1521 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1523 -- If the way mentions a street or place address, try that for parenting.
1524 IF location.address is not null THEN
1525 IF location.address ? 'street' THEN
1526 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1527 IF address_street_word_ids IS NOT NULL THEN
1528 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1529 EXIT WHEN NEW.parent_place_id is not NULL;
1532 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1534 IF location.address ? 'place' THEN
1535 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1536 IF address_street_word_ids IS NOT NULL THEN
1537 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1538 EXIT WHEN NEW.parent_place_id is not NULL;
1541 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1544 -- Is the WAY part of a relation
1545 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1547 -- At the moment we only process one type of relation - associatedStreet
1548 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1549 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1550 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1551 --RAISE WARNING 'node in way that is in a relation %',relation;
1552 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1553 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1558 EXIT WHEN NEW.parent_place_id is not null;
1559 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1564 -- Still nothing, just use the nearest road
1565 IF NEW.parent_place_id IS NULL THEN
1566 SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) INTO NEW.parent_place_id;
1568 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1571 -- If we didn't find any road fallback to standard method
1572 IF NEW.parent_place_id IS NOT NULL THEN
1574 -- Get the details of the parent road
1575 select s.country_code, s.name_vector, s.nameaddress_vector from search_name s
1576 where s.place_id = NEW.parent_place_id INTO location;
1577 NEW.country_code := location.country_code;
1578 --DEBUG: RAISE WARNING 'Got parent details from search name';
1580 -- determine postcode
1581 IF NEW.rank_search > 4 THEN
1582 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1583 NEW.postcode = upper(trim(NEW.address->'postcode'));
1585 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1587 IF NEW.postcode is null THEN
1588 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1592 -- If there is no name it isn't searchable, don't bother to create a search record
1593 IF NEW.name is NULL THEN
1594 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1598 -- Merge address from parent
1599 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1600 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1602 -- Performance, it would be more acurate to do all the rest of the import
1603 -- process but it takes too long
1604 -- Just be happy with inheriting from parent road only
1606 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1607 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
1608 --DEBUG: RAISE WARNING 'Place added to location table';
1611 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);
1612 --DEBUG: RAISE WARNING 'Place added to search table';
1619 -- ---------------------------------------------------------------------------
1621 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1623 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1625 -- see if we have any special relation members
1626 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1627 --DEBUG: RAISE WARNING 'Got relation members';
1629 IF relation_members IS NOT NULL THEN
1630 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1631 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1633 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1634 and osm_id = substring(relMember.member,2,10000)::bigint
1635 and class = 'place' order by rank_search desc limit 1 LOOP
1637 -- If we don't already have one use this as the centre point of the geometry
1638 IF NEW.centroid IS NULL THEN
1639 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1642 -- merge in the label name, re-init word vector
1643 IF NOT linkedPlacex.name IS NULL THEN
1644 NEW.name := linkedPlacex.name || NEW.name;
1645 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1648 -- merge in extra tags
1649 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1651 -- mark the linked place (excludes from search results)
1652 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1654 -- keep a note of the node id in case we need it for wikipedia in a bit
1655 linked_node_id := linkedPlacex.osm_id;
1656 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1657 --DEBUG: RAISE WARNING 'Linked label member';
1662 IF NEW.centroid IS NULL THEN
1664 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1665 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1667 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1668 and osm_id = substring(relMember.member,2,10000)::bigint
1669 and class = 'place' order by rank_search desc limit 1 LOOP
1671 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1672 -- But that can be fixed by explicitly setting the label in the data
1673 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1674 AND NEW.rank_address = linkedPlacex.rank_address THEN
1676 -- If we don't already have one use this as the centre point of the geometry
1677 IF NEW.centroid IS NULL THEN
1678 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1681 -- merge in the name, re-init word vector
1682 IF NOT linkedPlacex.name IS NULL THEN
1683 NEW.name := linkedPlacex.name || NEW.name;
1684 name_vector := make_keywords(NEW.name);
1687 -- merge in extra tags
1688 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1690 -- mark the linked place (excludes from search results)
1691 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1693 -- keep a note of the node id in case we need it for wikipedia in a bit
1694 linked_node_id := linkedPlacex.osm_id;
1695 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1696 --DEBUG: RAISE WARNING 'Linked admin_center';
1708 -- Name searches can be done for ways as well as relations
1709 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1711 -- not found one yet? how about doing a name search
1712 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1714 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1715 FOR linkedPlacex IN select placex.* from placex WHERE
1716 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1717 AND placex.rank_address = NEW.rank_address
1718 AND placex.place_id != NEW.place_id
1719 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1720 AND st_covers(NEW.geometry, placex.geometry)
1722 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1723 -- If we don't already have one use this as the centre point of the geometry
1724 IF NEW.centroid IS NULL THEN
1725 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1728 -- merge in the name, re-init word vector
1729 NEW.name := linkedPlacex.name || NEW.name;
1730 name_vector := make_keywords(NEW.name);
1732 -- merge in extra tags
1733 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1735 -- mark the linked place (excludes from search results)
1736 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1738 -- keep a note of the node id in case we need it for wikipedia in a bit
1739 linked_node_id := linkedPlacex.osm_id;
1740 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1741 --DEBUG: RAISE WARNING 'Linked named place';
1745 IF NEW.centroid IS NOT NULL THEN
1746 place_centroid := NEW.centroid;
1747 -- Place might have had only a name tag before but has now received translations
1748 -- from the linked place. Make sure a name tag for the default language exists in
1750 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1751 default_language := get_country_language_code(NEW.country_code);
1752 IF default_language IS NOT NULL THEN
1753 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1754 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1755 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1756 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1760 --DEBUG: RAISE WARNING 'Names updated from linked places';
1763 -- Use the maximum importance if a one could be computed from the linked object.
1764 IF linked_importance is not null AND
1765 (NEW.importance is null or NEW.importance < linked_importance) THEN
1766 NEW.importance = linked_importance;
1769 -- Still null? how about looking it up by the node id
1770 IF NEW.importance IS NULL THEN
1771 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1772 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;
1777 -- make sure all names are in the word table
1778 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R' THEN
1779 perform create_country(NEW.name, lower(NEW.country_code));
1780 --DEBUG: RAISE WARNING 'Country names updated';
1783 NEW.parent_place_id = 0;
1784 parent_place_id_rank = 0;
1787 -- convert address store to array of tokenids
1788 --DEBUG: RAISE WARNING 'Starting address search';
1789 isin_tokens := '{}'::int[];
1790 IF NEW.address IS NOT NULL THEN
1791 FOR addr_item IN SELECT * FROM each(NEW.address)
1793 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1794 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1795 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1796 isin_tokens := isin_tokens || address_street_word_id;
1798 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1799 IF address_street_word_id IS NOT NULL THEN
1800 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1803 IF addr_item.key = 'is_in' THEN
1804 -- is_in items need splitting
1805 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1806 IF array_upper(isin, 1) IS NOT NULL THEN
1807 FOR i IN 1..array_upper(isin, 1) LOOP
1808 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1809 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1810 isin_tokens := isin_tokens || address_street_word_id;
1813 -- merge word into address vector
1814 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1815 IF address_street_word_id IS NOT NULL THEN
1816 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1823 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1825 -- RAISE WARNING 'ISIN: %', isin_tokens;
1827 -- Process area matches
1828 location_rank_search := 0;
1829 location_distance := 0;
1830 location_parent := NULL;
1831 -- added ourself as address already
1832 address_havelevel[NEW.rank_address] := true;
1833 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1835 SELECT * from getNearFeatures(NEW.partition,
1836 CASE WHEN NEW.rank_search >= 26
1837 AND NEW.rank_search < 30
1839 ELSE place_centroid END,
1840 search_maxrank, isin_tokens)
1842 IF location.rank_address != location_rank_search THEN
1843 location_rank_search := location.rank_address;
1844 IF location.isguess THEN
1845 location_distance := location.distance * 1.5;
1847 IF location.rank_address <= 12 THEN
1848 -- for county and above, if we have an area consider that exact
1849 -- (It would be nice to relax the constraint for places close to
1850 -- the boundary but we'd need the exact geometry for that. Too
1852 location_distance = 0;
1854 -- Below county level remain slightly fuzzy.
1855 location_distance := location.distance * 0.5;
1859 CONTINUE WHEN location.keywords <@ location_keywords;
1862 IF location.distance < location_distance OR NOT location.isguess THEN
1863 location_keywords := location.keywords;
1865 location_isaddress := NOT address_havelevel[location.rank_address];
1866 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1867 location_isaddress := ST_Contains(location_parent,location.centroid);
1870 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1871 -- Add it to the list of search terms
1872 IF location.rank_search > 4 THEN
1873 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1875 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1876 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1878 IF location_isaddress THEN
1879 -- add postcode if we have one
1880 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1881 IF location.postcode is not null THEN
1882 NEW.postcode = location.postcode;
1885 address_havelevel[location.rank_address] := true;
1886 IF NOT location.isguess THEN
1887 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1890 IF location.rank_address > parent_place_id_rank THEN
1891 NEW.parent_place_id = location.place_id;
1892 parent_place_id_rank = location.rank_address;
1897 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1902 --DEBUG: RAISE WARNING 'address computed';
1904 IF NEW.address is not null AND NEW.address ? 'postcode'
1905 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1906 NEW.postcode := upper(trim(NEW.address->'postcode'));
1909 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1910 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1913 -- if we have a name add this to the name search table
1914 IF NEW.name IS NOT NULL THEN
1916 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1917 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
1918 --DEBUG: RAISE WARNING 'added to location (full)';
1921 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1922 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1923 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1926 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);
1927 --DEBUG: RAISE WARNING 'added to serach name (full)';
1931 -- If we've not managed to pick up a better one - default centroid
1932 IF NEW.centroid IS NULL THEN
1933 NEW.centroid := place_centroid;
1936 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1943 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1949 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1951 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1952 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1953 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1954 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1956 IF OLD.rank_address < 30 THEN
1958 -- mark everything linked to this place for re-indexing
1959 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1960 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1961 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1963 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1964 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1966 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1967 b := deleteRoad(OLD.partition, OLD.place_id);
1969 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1970 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1971 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1972 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1973 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1977 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1979 IF OLD.rank_address < 26 THEN
1980 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1983 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1985 IF OLD.name is not null THEN
1986 b := deleteSearchName(OLD.partition, OLD.place_id);
1989 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1991 DELETE FROM place_addressline where place_id = OLD.place_id;
1993 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1995 -- remove from tables for special search
1996 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1997 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1999 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2002 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2010 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2016 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2018 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2019 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2020 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;
2022 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2028 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;
2030 -- interpolations are special
2031 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2032 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2041 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2046 existingplacex RECORD;
2047 existingline RECORD;
2048 existinggeometry GEOMETRY;
2049 existingplace_id BIGINT;
2054 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2055 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2056 -- filter wrong tupels
2057 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
2058 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2059 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2060 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2064 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2065 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2066 -- Have we already done this place?
2067 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;
2069 -- Get the existing place_id
2070 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2072 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2073 IF existing.osm_type IS NULL THEN
2074 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2077 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2078 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2080 -- 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)
2081 IF existingline.osm_id IS NOT NULL THEN
2082 delete from location_property_osmline where osm_id = NEW.osm_id;
2085 -- for interpolations invalidate all nodes on the line
2086 update placex p set indexed_status = 2
2087 from planet_osm_ways w
2088 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2091 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2092 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2095 IF existing.osm_type IS NULL THEN
2099 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2100 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2101 OR existing.geometry::text != NEW.geometry::text
2106 address = NEW.address,
2107 extratags = NEW.extratags,
2108 admin_level = NEW.admin_level,
2109 geometry = NEW.geometry
2110 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2115 ELSE -- insert to placex
2117 -- Patch in additional country names
2118 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2119 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2120 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2121 IF existing.name IS NOT NULL THEN
2122 NEW.name = existing.name || NEW.name;
2126 -- Have we already done this place?
2127 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;
2129 -- Get the existing place_id
2130 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;
2132 -- Handle a place changing type by removing the old data
2133 -- My generated 'place' types are causing havok because they overlap with real keys
2134 -- TODO: move them to their own special purpose key/class to avoid collisions
2135 IF existing.osm_type IS NULL THEN
2136 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2139 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2140 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2143 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2144 AND st_area(existing.geometry) > 0.02
2145 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2146 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2148 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2149 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2150 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2154 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2155 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2157 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2158 IF existingplacex.osm_type IS NULL OR
2159 (existingplacex.class = 'boundary' AND
2160 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2161 (existingplacex.type != NEW.type)))
2164 IF existingplacex.osm_type IS NOT NULL THEN
2165 -- sanity check: ignore admin_level changes on places with too many active children
2166 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2167 --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;
2168 --LIMIT INDEXING: IF i > 100000 THEN
2169 --LIMIT INDEXING: RETURN null;
2170 --LIMIT INDEXING: END IF;
2173 IF existing.osm_type IS NOT NULL THEN
2174 -- pathological case caused by the triggerless copy into place during initial import
2175 -- force delete even for large areas, it will be reinserted later
2176 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;
2177 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2180 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2181 insert into placex (osm_type, osm_id, class, type, name,
2182 admin_level, address, extratags, geometry)
2183 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2184 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2186 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2191 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2192 IF existing.geometry::text != NEW.geometry::text
2193 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2194 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2197 -- Get the version of the geometry actually used (in placex table)
2198 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;
2200 -- Performance limit
2201 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2203 -- 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
2204 update placex set indexed_status = 2 where indexed_status = 0 and
2205 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2206 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2207 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2209 update placex set indexed_status = 2 where indexed_status = 0 and
2210 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2211 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2212 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2219 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2220 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2221 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2222 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2223 OR existing.geometry::text != NEW.geometry::text
2228 address = NEW.address,
2229 extratags = NEW.extratags,
2230 admin_level = NEW.admin_level,
2231 geometry = NEW.geometry
2232 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2235 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2236 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2237 -- postcode was deleted, no longer retain in placex
2238 DELETE FROM placex where place_id = existingplacex.place_id;
2242 NEW.name := hstore('ref', NEW.address->'postcode');
2245 IF NEW.class in ('boundary')
2246 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2247 DELETE FROM placex where place_id = existingplacex.place_id;
2253 address = NEW.address,
2254 parent_place_id = null,
2255 extratags = NEW.extratags,
2256 admin_level = NEW.admin_level,
2258 geometry = NEW.geometry
2259 where place_id = existingplacex.place_id;
2261 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2262 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2263 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2264 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2265 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);
2268 -- linked places should get potential new naming and addresses
2269 IF existingplacex.linked_place_id is not NULL THEN
2272 extratags = p.extratags,
2275 where x.place_id = existingplacex.linked_place_id
2276 and x.indexed_status = 0
2277 and x.osm_type = p.osm_type
2278 and x.osm_id = p.osm_id
2279 and x.class = p.class;
2284 -- Abort the add (we modified the existing place instead)
2289 $$ LANGUAGE plpgsql;
2292 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2297 IF name is null THEN
2301 FOR j IN 1..array_upper(languagepref,1) LOOP
2302 IF name ? languagepref[j] THEN
2303 result := trim(name->languagepref[j]);
2304 IF result != '' THEN
2310 -- anything will do as a fallback - just take the first name type thing there is
2311 RETURN trim((avals(name))[1]);
2314 LANGUAGE plpgsql IMMUTABLE;
2316 --housenumber only needed for tiger data
2317 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2329 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2330 currresult := trim(get_name_by_language(location.name, languagepref));
2331 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2332 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2333 prevresult := currresult;
2337 RETURN array_to_string(result,', ');
2342 DROP TYPE IF EXISTS addressline CASCADE;
2343 create type addressline as (
2350 admin_level INTEGER,
2353 rank_address INTEGER,
2357 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2360 for_place_id BIGINT;
2365 countrylocation RECORD;
2366 searchcountrycode varchar(2);
2367 searchhousenumber TEXT;
2368 searchhousename HSTORE;
2369 searchrankaddress INTEGER;
2370 searchpostcode TEXT;
2376 -- first query osmline (interpolation lines)
2377 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2378 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2379 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2380 IF for_place_id IS NOT NULL THEN
2381 searchhousenumber = in_housenumber::text;
2384 --then query tiger data
2385 -- %NOTIGERDATA% IF 0 THEN
2386 IF for_place_id IS NULL THEN
2387 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2388 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2389 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2390 IF for_place_id IS NOT NULL THEN
2391 searchhousenumber = in_housenumber::text;
2394 -- %NOTIGERDATA% END IF;
2396 -- %NOAUXDATA% IF 0 THEN
2397 IF for_place_id IS NULL THEN
2398 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2399 WHERE place_id = in_place_id
2400 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2402 -- %NOAUXDATA% END IF;
2405 IF for_place_id IS NULL THEN
2406 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2407 FROM location_postcode
2408 WHERE place_id = in_place_id
2409 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2412 IF for_place_id IS NULL THEN
2413 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2414 WHERE place_id = in_place_id and rank_search > 27
2415 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2418 IF for_place_id IS NULL THEN
2419 select coalesce(linked_place_id, place_id), country_code,
2420 housenumber, rank_search, postcode, null
2421 from placex where place_id = in_place_id
2422 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2425 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2428 hadcountry := false;
2430 select placex.place_id, osm_type, osm_id, name,
2431 class, type, admin_level, true as isaddress,
2432 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2433 0 as distance, country_code, postcode
2435 where place_id = for_place_id
2437 --RAISE WARNING '%',location;
2438 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2439 searchcountrycode := location.country_code;
2441 IF location.type in ('postcode', 'postal_code') THEN
2442 location.isaddress := FALSE;
2443 ELSEIF location.rank_address = 4 THEN
2446 IF location.rank_address < 4 AND NOT hadcountry THEN
2447 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2448 IF countryname IS NOT NULL THEN
2449 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2450 RETURN NEXT countrylocation;
2453 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2454 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2455 location.distance)::addressline;
2456 RETURN NEXT countrylocation;
2457 found := location.rank_address;
2461 select placex.place_id, osm_type, osm_id, name,
2462 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2463 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2464 admin_level, fromarea, isaddress,
2465 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,
2466 distance,country_code,postcode
2467 from place_addressline join placex on (address_place_id = placex.place_id)
2468 where place_addressline.place_id = for_place_id
2469 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2470 and address_place_id != for_place_id and linked_place_id is null
2471 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2472 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2474 --RAISE WARNING '%',location;
2475 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2476 searchcountrycode := location.country_code;
2478 IF location.type in ('postcode', 'postal_code') THEN
2479 location.isaddress := FALSE;
2481 IF location.rank_address = 4 AND location.isaddress THEN
2484 IF location.rank_address < 4 AND NOT hadcountry THEN
2485 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2486 IF countryname IS NOT NULL THEN
2487 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2488 RETURN NEXT countrylocation;
2491 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2492 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2493 location.distance)::addressline;
2494 RETURN NEXT countrylocation;
2495 found := location.rank_address;
2499 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2500 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2501 IF countryname IS NOT NULL THEN
2502 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2503 RETURN NEXT location;
2507 IF searchcountrycode IS NOT NULL THEN
2508 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2509 RETURN NEXT location;
2512 IF searchhousename IS NOT NULL THEN
2513 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2514 RETURN NEXT location;
2517 IF searchhousenumber IS NOT NULL THEN
2518 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2519 RETURN NEXT location;
2522 IF searchpostcode IS NOT NULL THEN
2523 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2524 RETURN NEXT location;
2533 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2539 ELSEIF rank < 4 THEN
2541 ELSEIF rank < 8 THEN
2543 ELSEIF rank < 12 THEN
2545 ELSEIF rank < 16 THEN
2547 ELSEIF rank = 16 THEN
2549 ELSEIF rank = 17 THEN
2550 RETURN 'Town / Island';
2551 ELSEIF rank = 18 THEN
2552 RETURN 'Village / Hamlet';
2553 ELSEIF rank = 20 THEN
2555 ELSEIF rank = 21 THEN
2556 RETURN 'Postcode Area';
2557 ELSEIF rank = 22 THEN
2558 RETURN 'Croft / Farm / Locality / Islet';
2559 ELSEIF rank = 23 THEN
2560 RETURN 'Postcode Area';
2561 ELSEIF rank = 25 THEN
2562 RETURN 'Postcode Point';
2563 ELSEIF rank = 26 THEN
2564 RETURN 'Street / Major Landmark';
2565 ELSEIF rank = 27 THEN
2566 RETURN 'Minory Street / Path';
2567 ELSEIF rank = 28 THEN
2568 RETURN 'House / Building';
2570 RETURN 'Other: '||rank;
2577 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2583 ELSEIF rank < 2 THEN
2585 ELSEIF rank < 4 THEN
2587 ELSEIF rank = 5 THEN
2589 ELSEIF rank < 8 THEN
2591 ELSEIF rank < 12 THEN
2593 ELSEIF rank < 16 THEN
2595 ELSEIF rank = 16 THEN
2597 ELSEIF rank = 17 THEN
2598 RETURN 'Town / Village / Hamlet';
2599 ELSEIF rank = 20 THEN
2601 ELSEIF rank = 21 THEN
2602 RETURN 'Postcode Area';
2603 ELSEIF rank = 22 THEN
2604 RETURN 'Croft / Farm / Locality / Islet';
2605 ELSEIF rank = 23 THEN
2606 RETURN 'Postcode Area';
2607 ELSEIF rank = 25 THEN
2608 RETURN 'Postcode Point';
2609 ELSEIF rank = 26 THEN
2610 RETURN 'Street / Major Landmark';
2611 ELSEIF rank = 27 THEN
2612 RETURN 'Minory Street / Path';
2613 ELSEIF rank = 28 THEN
2614 RETURN 'House / Building';
2616 RETURN 'Other: '||rank;
2623 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2624 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2629 place_centroid GEOMETRY;
2630 out_partition INTEGER;
2631 out_parent_place_id BIGINT;
2633 address_street_word_id INTEGER;
2638 place_centroid := ST_Centroid(pointgeo);
2639 out_partition := get_partition(in_countrycode);
2640 out_parent_place_id := null;
2642 address_street_word_id := get_name_id(make_standard_name(in_street));
2643 IF address_street_word_id IS NOT NULL THEN
2644 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2645 out_parent_place_id := location.place_id;
2649 IF out_parent_place_id IS NULL THEN
2650 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2651 out_parent_place_id := location.place_id;
2655 out_postcode := in_postcode;
2656 IF out_postcode IS NULL THEN
2657 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2659 -- XXX look into postcode table
2662 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2663 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2664 newpoints := newpoints + 1;
2671 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2678 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2679 IF members[i+1] = member THEN
2680 result := result || members[i];
2689 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2695 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2696 IF members[i+1] = ANY(memberLabels) THEN
2697 RETURN NEXT members[i];
2706 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2707 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2709 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2710 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
2711 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2712 ), '') AS bytea), 'UTF8');
2714 LANGUAGE SQL IMMUTABLE STRICT;
2716 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2720 RETURN decode_url_part(p);
2722 WHEN others THEN return null;
2725 LANGUAGE plpgsql IMMUTABLE;
2727 DROP TYPE wikipedia_article_match CASCADE;
2728 create type wikipedia_article_match as (
2734 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2740 wiki_article_title TEXT;
2741 wiki_article_language TEXT;
2742 result wikipedia_article_match;
2744 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'];
2746 WHILE langs[i] IS NOT NULL LOOP
2747 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2748 IF wiki_article is not null THEN
2749 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2750 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2751 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2752 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2753 wiki_article := replace(wiki_article,' ','_');
2754 IF strpos(wiki_article, ':') IN (3,4) THEN
2755 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2756 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2758 wiki_article_title := trim(wiki_article);
2759 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;
2762 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2763 from wikipedia_article
2764 where language = wiki_article_language and
2765 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2767 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2768 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2769 where wikipedia_redirect.language = wiki_article_language and
2770 (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'\\',''))
2771 order by importance desc limit 1 INTO result;
2773 IF result.language is not null THEN
2784 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2785 RETURNS SETOF GEOMETRY
2799 remainingdepth INTEGER;
2804 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2806 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2807 RETURN NEXT geometry;
2811 remainingdepth := maxdepth - 1;
2812 area := ST_AREA(geometry);
2813 IF remainingdepth < 1 OR area < maxarea THEN
2814 RETURN NEXT geometry;
2818 xmin := st_xmin(geometry);
2819 xmax := st_xmax(geometry);
2820 ymin := st_ymin(geometry);
2821 ymax := st_ymax(geometry);
2822 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2824 -- if the geometry completely covers the box don't bother to slice any more
2825 IF ST_AREA(secbox) = area THEN
2826 RETURN NEXT geometry;
2830 xmid := (xmin+xmax)/2;
2831 ymid := (ymin+ymax)/2;
2834 FOR seg IN 1..4 LOOP
2837 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2840 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2843 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2846 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2849 IF st_intersects(geometry, secbox) THEN
2850 secgeo := st_intersection(geometry, secbox);
2851 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2852 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2853 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2855 RETURN NEXT geo.geom;
2867 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2868 RETURNS SETOF GEOMETRY
2873 -- 10000000000 is ~~ 1x1 degree
2874 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2875 RETURN NEXT geo.geom;
2883 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2887 osmtype character(1);
2891 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2892 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2893 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2894 -- force delete from place/placex by making it a very small geometry
2895 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;
2896 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2903 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2911 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2912 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2913 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2914 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2915 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2916 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2917 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'));
2918 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2919 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'));
2925 ELSEIF rank < 18 THEN
2927 ELSEIF rank < 20 THEN
2929 ELSEIF rank = 21 THEN
2931 ELSEIF rank < 24 THEN
2933 ELSEIF rank < 26 THEN
2934 diameter := 0.002; -- 100 to 200 meters
2935 ELSEIF rank < 28 THEN
2936 diameter := 0.001; -- 50 to 100 meters
2938 IF diameter > 0 THEN
2940 -- roads may cause reparenting for >27 rank places
2941 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2942 ELSEIF rank >= 16 THEN
2943 -- up to rank 16, street-less addresses may need reparenting
2944 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');
2946 -- for all other places the search terms may change as well
2947 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);