1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
261 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
268 postcode := upper(postcode);
270 IF country_code = 'gb' THEN
271 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
274 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
277 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
282 ELSEIF country_code = 'sg' THEN
283 IF postcode ~ '^([0-9]{6})$' THEN
288 ELSEIF country_code = 'de' THEN
289 IF postcode ~ '^([0-9]{5})$' THEN
295 -- Guess at the postcode format and coverage (!)
296 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
300 -- Does it look splitable into and area and local code?
301 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
303 IF part IS NOT NULL THEN
306 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
315 LANGUAGE plpgsql IMMUTABLE;
317 -- Find the nearest artificial postcode for the given geometry.
318 -- TODO For areas there should not be more than two inside the geometry.
319 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
325 -- If the geometry is an area then only one postcode must be within
326 -- that area, otherwise consider the area as not having a postcode.
327 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
328 SELECT min(postcode), count(*) FROM
329 (SELECT postcode FROM location_postcode
330 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
340 SELECT postcode FROM location_postcode
341 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
342 AND location_postcode.country_code = country
343 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
352 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
361 FOR item IN SELECT (each(src)).* LOOP
363 s := make_standard_name(item.value);
364 w := getorcreate_country(s, lookup_country_code);
366 words := regexp_split_to_array(item.value, E'[,;()]');
367 IF array_upper(words, 1) != 1 THEN
368 FOR j IN 1..array_upper(words, 1) LOOP
369 s := make_standard_name(words[j]);
371 w := getorcreate_country(s, lookup_country_code);
380 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
390 result := '{}'::INTEGER[];
392 FOR item IN SELECT (each(src)).* LOOP
394 s := make_standard_name(item.value);
396 w := getorcreate_name_id(s, item.value);
398 IF not(ARRAY[w] <@ result) THEN
399 result := result || w;
402 w := getorcreate_word_id(s);
404 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
405 result := result || w;
408 words := string_to_array(s, ' ');
409 IF array_upper(words, 1) IS NOT NULL THEN
410 FOR j IN 1..array_upper(words, 1) LOOP
411 IF (words[j] != '') THEN
412 w = getorcreate_word_id(words[j]);
413 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
414 result := result || w;
420 words := regexp_split_to_array(item.value, E'[,;()]');
421 IF array_upper(words, 1) != 1 THEN
422 FOR j IN 1..array_upper(words, 1) LOOP
423 s := make_standard_name(words[j]);
425 w := getorcreate_word_id(s);
426 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
433 s := regexp_replace(item.value, '市$', '');
434 IF s != item.value THEN
435 s := make_standard_name(s);
437 w := getorcreate_name_id(s, item.value);
438 IF NOT (ARRAY[w] <@ result) THEN
439 result := result || w;
449 LANGUAGE plpgsql IMMUTABLE;
451 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
461 result := '{}'::INTEGER[];
463 s := make_standard_name(src);
464 w := getorcreate_name_id(s, src);
466 IF NOT (ARRAY[w] <@ result) THEN
467 result := result || w;
470 w := getorcreate_word_id(s);
472 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
473 result := result || w;
476 words := string_to_array(s, ' ');
477 IF array_upper(words, 1) IS NOT NULL THEN
478 FOR j IN 1..array_upper(words, 1) LOOP
479 IF (words[j] != '') THEN
480 w = getorcreate_word_id(words[j]);
481 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
482 result := result || w;
488 words := regexp_split_to_array(src, E'[,;()]');
489 IF array_upper(words, 1) != 1 THEN
490 FOR j IN 1..array_upper(words, 1) LOOP
491 s := make_standard_name(words[j]);
493 w := getorcreate_word_id(s);
494 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
495 result := result || w;
501 s := regexp_replace(src, '市$', '');
503 s := make_standard_name(s);
505 w := getorcreate_name_id(s, src);
506 IF NOT (ARRAY[w] <@ result) THEN
507 result := result || w;
515 LANGUAGE plpgsql IMMUTABLE;
517 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
520 place_centre GEOMETRY;
523 place_centre := ST_PointOnSurface(place);
525 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
527 -- Try for a OSM polygon
528 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
530 RETURN nearcountry.country_code;
533 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
535 -- Try for OSM fallback data
536 -- The order is to deal with places like HongKong that are 'states' within another polygon
537 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
539 RETURN nearcountry.country_code;
542 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
544 -- Natural earth data
545 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
547 RETURN nearcountry.country_code;
550 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
553 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
555 RETURN nearcountry.country_code;
558 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
560 -- Natural earth data
561 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
563 RETURN nearcountry.country_code;
569 LANGUAGE plpgsql IMMUTABLE;
571 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
576 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
578 RETURN lower(nearcountry.country_default_language_code);
583 LANGUAGE plpgsql IMMUTABLE;
585 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
590 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
592 RETURN lower(nearcountry.country_default_language_codes);
597 LANGUAGE plpgsql IMMUTABLE;
599 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
604 FOR nearcountry IN select partition from country_name where country_code = in_country_code
606 RETURN nearcountry.partition;
611 LANGUAGE plpgsql IMMUTABLE;
613 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
617 DELETE FROM location_area where place_id = OLD_place_id;
618 -- TODO:location_area
624 CREATE OR REPLACE FUNCTION add_location(
626 country_code varchar(2),
630 rank_address INTEGER,
646 IF rank_search > 25 THEN
647 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
650 x := deleteLocationArea(partition, place_id, rank_search);
652 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
654 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
655 postcode := upper(trim (in_postcode));
658 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
659 centroid := ST_Centroid(geometry);
661 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
662 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
668 IF rank_address = 0 THEN
670 ELSEIF rank_search <= 14 THEN
672 ELSEIF rank_search <= 15 THEN
674 ELSEIF rank_search <= 16 THEN
676 ELSEIF rank_search <= 17 THEN
678 ELSEIF rank_search <= 21 THEN
680 ELSEIF rank_search = 25 THEN
684 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
686 secgeo := ST_Buffer(geometry, diameter);
687 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
697 -- find the parent road of the cut road parts
698 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
699 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
704 parent_place_id BIGINT;
705 address_street_word_ids INTEGER[];
711 addr_street = street;
714 IF addr_street is null and addr_place is null THEN
715 select nodes from planet_osm_ways where id = wayid INTO waynodes;
716 FOR location IN SELECT placex.address from placex
717 where osm_type = 'N' and osm_id = ANY(waynodes)
718 and placex.address is not null
719 and (placex.address ? 'street' or placex.address ? 'place')
720 and indexed_status < 100
722 addr_street = location.address->'street';
723 addr_place = location.address->'place';
727 IF addr_street IS NOT NULL THEN
728 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
729 IF address_street_word_ids IS NOT NULL THEN
730 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
731 parent_place_id := location.place_id;
736 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
737 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
738 IF address_street_word_ids IS NOT NULL THEN
739 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
740 parent_place_id := location.place_id;
745 IF parent_place_id is null THEN
746 FOR location IN SELECT place_id FROM placex
747 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
748 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
749 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
750 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
752 parent_place_id := location.place_id;
756 IF parent_place_id is null THEN
760 RETURN parent_place_id;
766 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
769 NEW.place_id := nextval('seq_place');
770 NEW.indexed_date := now();
772 IF NEW.indexed_status IS NULL THEN
773 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
774 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
775 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
779 NEW.indexed_status := 1; --STATUS_NEW
780 NEW.country_code := lower(get_country_code(NEW.linegeo));
782 NEW.partition := get_partition(NEW.country_code);
783 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
792 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
798 country_code VARCHAR(2);
799 default_language VARCHAR(10);
804 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
806 NEW.place_id := nextval('seq_place');
807 NEW.indexed_status := 1; --STATUS_NEW
809 NEW.country_code := lower(get_country_code(NEW.geometry));
811 NEW.partition := get_partition(NEW.country_code);
812 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
814 -- copy 'name' to or from the default language (if there is a default language)
815 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
816 default_language := get_country_language_code(NEW.country_code);
817 IF default_language IS NOT NULL THEN
818 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
819 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
820 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
821 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
826 IF NEW.osm_type = 'X' THEN
827 -- E'X'ternal records should already be in the right format so do nothing
829 NEW.rank_search := 30;
830 NEW.rank_address := NEW.rank_search;
832 -- By doing in postgres we have the country available to us - currently only used for postcode
833 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
835 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
836 -- most likely just a part of a multipolygon postcode boundary, throw it away
840 NEW.name := hstore('ref', NEW.address->'postcode');
842 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
843 INTO NEW.rank_search, NEW.rank_address;
845 ELSEIF NEW.class = 'place' THEN
846 IF NEW.type in ('continent') THEN
847 NEW.rank_search := 2;
848 NEW.rank_address := NEW.rank_search;
849 NEW.country_code := NULL;
850 ELSEIF NEW.type in ('sea') THEN
851 NEW.rank_search := 2;
852 NEW.rank_address := 0;
853 NEW.country_code := NULL;
854 ELSEIF NEW.type in ('country') THEN
855 NEW.rank_search := 4;
856 NEW.rank_address := NEW.rank_search;
857 ELSEIF NEW.type in ('state') THEN
858 NEW.rank_search := 8;
859 NEW.rank_address := NEW.rank_search;
860 ELSEIF NEW.type in ('region') THEN
861 NEW.rank_search := 18; -- dropped from previous value of 10
862 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
863 ELSEIF NEW.type in ('county') THEN
864 NEW.rank_search := 12;
865 NEW.rank_address := NEW.rank_search;
866 ELSEIF NEW.type in ('city') THEN
867 NEW.rank_search := 16;
868 NEW.rank_address := NEW.rank_search;
869 ELSEIF NEW.type in ('island') THEN
870 NEW.rank_search := 17;
871 NEW.rank_address := 0;
872 ELSEIF NEW.type in ('town') THEN
873 NEW.rank_search := 18;
874 NEW.rank_address := 16;
875 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
876 NEW.rank_search := 19;
877 NEW.rank_address := 16;
878 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
879 NEW.rank_search := 20;
880 NEW.rank_address := NEW.rank_search;
881 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
882 NEW.rank_search := 20;
883 NEW.rank_address := 0;
884 -- Irish townlands, tagged as place=locality and locality=townland
885 IF (NEW.extratags -> 'locality') = 'townland' THEN
886 NEW.rank_address := 20;
888 ELSEIF NEW.type in ('neighbourhood') THEN
889 NEW.rank_search := 22;
890 NEW.rank_address := 22;
891 ELSEIF NEW.type in ('house','building') THEN
892 NEW.rank_search := 30;
893 NEW.rank_address := NEW.rank_search;
894 ELSEIF NEW.type in ('houses') THEN
895 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
896 NEW.rank_search := 28;
897 NEW.rank_address := 0;
900 ELSEIF NEW.class = 'boundary' THEN
901 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
902 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
905 NEW.rank_search := NEW.admin_level * 2;
906 IF NEW.type = 'administrative' THEN
907 NEW.rank_address := NEW.rank_search;
909 NEW.rank_address := 0;
911 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
912 NEW.rank_search := 22;
913 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
914 NEW.rank_address := NEW.rank_search;
916 NEW.rank_address := 0;
918 ELSEIF NEW.class = 'leisure' and NEW.type in ('park') THEN
919 NEW.rank_search := 24;
920 NEW.rank_address := 0;
921 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
922 NEW.rank_search := 18;
923 NEW.rank_address := 0;
924 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
925 NEW.rank_search := 4;
926 NEW.rank_address := NEW.rank_search;
927 -- any feature more than 5 square miles is probably worth indexing
928 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
929 NEW.rank_search := 22;
930 NEW.rank_address := 0;
931 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
933 ELSEIF NEW.class = 'waterway' THEN
934 IF NEW.osm_type = 'R' THEN
935 NEW.rank_search := 16;
937 NEW.rank_search := 17;
939 NEW.rank_address := 0;
940 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
941 NEW.rank_search := 27;
942 NEW.rank_address := NEW.rank_search;
943 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
944 NEW.rank_search := 26;
945 NEW.rank_address := NEW.rank_search;
946 ELSEIF NEW.class = 'mountain_pass' THEN
947 NEW.rank_search := 20;
948 NEW.rank_address := 0;
953 IF NEW.rank_search > 30 THEN
954 NEW.rank_search := 30;
957 IF NEW.rank_address > 30 THEN
958 NEW.rank_address := 30;
961 IF (NEW.extratags -> 'capital') = 'yes' THEN
962 NEW.rank_search := NEW.rank_search - 1;
965 -- a country code make no sense below rank 4 (country)
966 IF NEW.rank_search < 4 THEN
967 NEW.country_code := NULL;
970 -- Block import below rank 22
971 -- IF NEW.rank_search > 22 THEN
975 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
977 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
979 IF NEW.rank_address > 0 THEN
980 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
981 -- Performance: We just can't handle re-indexing for country level changes
982 IF st_area(NEW.geometry) < 1 THEN
983 -- mark items within the geometry for re-indexing
984 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
986 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
987 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
988 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'));
989 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
990 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'));
993 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
995 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
996 IF NEW.type='postcode' THEN
998 ELSEIF NEW.rank_search < 16 THEN
1000 ELSEIF NEW.rank_search < 18 THEN
1002 ELSEIF NEW.rank_search < 20 THEN
1004 ELSEIF NEW.rank_search = 21 THEN
1006 ELSEIF NEW.rank_search < 24 THEN
1008 ELSEIF NEW.rank_search < 26 THEN
1009 diameter := 0.002; -- 100 to 200 meters
1010 ELSEIF NEW.rank_search < 28 THEN
1011 diameter := 0.001; -- 50 to 100 meters
1013 IF diameter > 0 THEN
1014 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1015 IF NEW.rank_search >= 26 THEN
1016 -- roads may cause reparenting for >27 rank places
1017 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1018 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1019 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1020 ELSEIF NEW.rank_search >= 16 THEN
1021 -- up to rank 16, street-less addresses may need reparenting
1022 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');
1024 -- for all other places the search terms may change as well
1025 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);
1032 -- add to tables for special search
1033 -- Note: won't work on initial import because the classtype tables
1034 -- do not yet exist. It won't hurt either.
1035 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1036 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1038 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1039 USING NEW.place_id, ST_Centroid(NEW.geometry);
1048 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1052 place_centroid GEOMETRY;
1056 startnumber INTEGER;
1061 sectiongeo GEOMETRY;
1062 interpol_postcode TEXT;
1066 IF OLD.indexed_status = 100 THEN
1067 delete from location_property_osmline where place_id = OLD.place_id;
1071 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1075 NEW.interpolationtype = NEW.address->'interpolation';
1077 place_centroid := ST_PointOnSurface(NEW.linegeo);
1078 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1079 NEW.address->'place',
1080 NEW.partition, place_centroid, NEW.linegeo);
1082 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1083 interpol_postcode := NEW.address->'postcode';
1084 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1086 interpol_postcode := NULL;
1089 -- if the line was newly inserted, split the line as necessary
1090 IF OLD.indexed_status = 1 THEN
1091 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1093 IF array_upper(waynodes, 1) IS NULL THEN
1097 linegeo := NEW.linegeo;
1098 startnumber := NULL;
1100 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1102 select osm_id, address, geometry
1103 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1104 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1105 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1106 IF nextnode.osm_id IS NOT NULL THEN
1107 --RAISE NOTICE 'place_id is not null';
1108 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1109 -- Make sure that the point is actually on the line. That might
1110 -- be a bit paranoid but ensures that the algorithm still works
1111 -- should osm2pgsql attempt to repair geometries.
1112 splitline := split_line_on_node(linegeo, nextnode.geometry);
1113 sectiongeo := ST_GeometryN(splitline, 1);
1114 linegeo := ST_GeometryN(splitline, 2);
1116 sectiongeo = linegeo;
1118 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1120 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1121 AND startnumber != endnumber
1122 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1124 IF (startnumber > endnumber) THEN
1125 housenum := endnumber;
1126 endnumber := startnumber;
1127 startnumber := housenum;
1128 sectiongeo := ST_Reverse(sectiongeo);
1131 -- determine postcode
1132 postcode := coalesce(interpol_postcode,
1133 prevnode.address->'postcode',
1134 nextnode.address->'postcode',
1137 IF postcode is NULL THEN
1138 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1140 IF postcode is NULL THEN
1141 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1144 IF NEW.startnumber IS NULL THEN
1145 NEW.startnumber := startnumber;
1146 NEW.endnumber := endnumber;
1147 NEW.linegeo := sectiongeo;
1148 NEW.postcode := upper(trim(postcode));
1150 insert into location_property_osmline
1151 (linegeo, partition, osm_id, parent_place_id,
1152 startnumber, endnumber, interpolationtype,
1153 address, postcode, country_code,
1154 geometry_sector, indexed_status)
1155 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1156 startnumber, endnumber, NEW.interpolationtype,
1157 NEW.address, postcode,
1158 NEW.country_code, NEW.geometry_sector, 0);
1162 -- early break if we are out of line string,
1163 -- might happen when a line string loops back on itself
1164 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1168 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1169 prevnode := nextnode;
1174 -- marking descendants for reparenting is not needed, because there are
1175 -- actually no descendants for interpolation lines
1181 -- Trigger for updates of location_postcode
1183 -- Computes the parent object the postcode most likely refers to.
1184 -- This will be the place that determines the address displayed when
1185 -- searching for this postcode.
1186 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1193 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1197 NEW.indexed_date = now();
1199 partition := get_partition(NEW.country_code);
1201 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1202 INTO NEW.rank_search, NEW.rank_address;
1204 NEW.parent_place_id = 0;
1207 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1208 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1210 NEW.parent_place_id = location.place_id;
1218 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1223 place_centroid GEOMETRY;
1225 search_maxdistance FLOAT[];
1226 search_mindistance FLOAT[];
1227 address_havelevel BOOLEAN[];
1234 relation_members TEXT[];
1236 linkedplacex RECORD;
1237 search_diameter FLOAT;
1238 search_prevdiameter FLOAT;
1239 search_maxrank INTEGER;
1240 address_maxrank INTEGER;
1241 address_street_word_id INTEGER;
1242 address_street_word_ids INTEGER[];
1243 parent_place_id_rank BIGINT;
1251 location_rank_search INTEGER;
1252 location_distance FLOAT;
1253 location_parent GEOMETRY;
1254 location_isaddress BOOLEAN;
1255 location_keywords INTEGER[];
1257 default_language TEXT;
1258 name_vector INTEGER[];
1259 nameaddress_vector INTEGER[];
1261 linked_node_id BIGINT;
1262 linked_importance FLOAT;
1263 linked_wikipedia TEXT;
1268 IF OLD.indexed_status = 100 THEN
1269 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1270 delete from placex where place_id = OLD.place_id;
1274 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1278 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1280 NEW.indexed_date = now();
1282 result := deleteSearchName(NEW.partition, NEW.place_id);
1283 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1284 result := deleteRoad(NEW.partition, NEW.place_id);
1285 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1286 UPDATE placex set linked_place_id = null, indexed_status = 2
1287 where linked_place_id = NEW.place_id;
1288 -- update not necessary for osmline, cause linked_place_id does not exist
1290 IF NEW.linked_place_id is not null THEN
1291 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1295 --DEBUG: RAISE WARNING 'Copy over address tags';
1296 IF NEW.address is not NULL THEN
1297 IF NEW.address ? 'conscriptionnumber' THEN
1298 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1299 IF NEW.address ? 'streetnumber' THEN
1300 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1301 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1303 NEW.housenumber := NEW.address->'conscriptionnumber';
1305 ELSEIF NEW.address ? 'streetnumber' THEN
1306 NEW.housenumber := NEW.address->'streetnumber';
1307 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1308 ELSEIF NEW.address ? 'housenumber' THEN
1309 NEW.housenumber := NEW.address->'housenumber';
1310 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1313 addr_street = NEW.address->'street';
1314 addr_place = NEW.address->'place';
1316 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1317 i := getorcreate_postcode_id(NEW.address->'postcode');
1321 -- Speed up searches - just use the centroid of the feature
1322 -- cheaper but less acurate
1323 place_centroid := ST_PointOnSurface(NEW.geometry);
1324 NEW.centroid := null;
1325 NEW.postcode := null;
1326 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1328 -- recalculate country and partition
1329 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1330 -- for countries, believe the mapped country code,
1331 -- so that we remain in the right partition if the boundaries
1333 NEW.country_code := lower(NEW.address->'country');
1334 NEW.partition := get_partition(lower(NEW.country_code));
1335 IF NEW.partition = 0 THEN
1336 NEW.country_code := lower(get_country_code(place_centroid));
1337 NEW.partition := get_partition(NEW.country_code);
1340 IF NEW.rank_search >= 4 THEN
1341 NEW.country_code := lower(get_country_code(place_centroid));
1343 NEW.country_code := NULL;
1345 NEW.partition := get_partition(NEW.country_code);
1347 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1349 -- waterway ways are linked when they are part of a relation and have the same class/type
1350 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1351 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1353 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1354 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1355 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1356 FOR linked_node_id IN SELECT place_id FROM placex
1357 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1358 and class = NEW.class and type = NEW.type
1359 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1361 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1366 --DEBUG: RAISE WARNING 'Waterway processed';
1369 -- Adding ourselves to the list simplifies address calculations later
1370 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1371 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1373 -- What level are we searching from
1374 search_maxrank := NEW.rank_search;
1376 -- Thought this wasn't needed but when we add new languages to the country_name table
1377 -- we need to update the existing names
1378 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1379 default_language := get_country_language_code(NEW.country_code);
1380 IF default_language IS NOT NULL THEN
1381 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1382 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1383 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1384 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1388 --DEBUG: RAISE WARNING 'Local names updated';
1390 -- Initialise the name vector using our name
1391 name_vector := make_keywords(NEW.name);
1392 nameaddress_vector := '{}'::int[];
1395 address_havelevel[i] := false;
1398 NEW.importance := null;
1399 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1400 IF NEW.importance IS NULL THEN
1401 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;
1404 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1406 -- ---------------------------------------------------------------------------
1407 -- For low level elements we inherit from our parent road
1408 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1410 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1412 -- We won't get a better centroid, besides these places are too small to care
1413 NEW.centroid := place_centroid;
1415 NEW.parent_place_id := null;
1417 -- if we have a POI and there is no address information,
1418 -- see if we can get it from a surrounding building
1419 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1420 AND NEW.housenumber IS NULL THEN
1421 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1422 and address is not null
1423 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1424 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1427 NEW.housenumber := location.address->'housenumber';
1428 addr_street := location.address->'street';
1429 addr_place := location.address->'place';
1430 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1434 -- We have to find our parent road.
1435 -- Copy data from linked items (points on ways, addr:street links, relations)
1437 -- Is this object part of a relation?
1438 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1440 -- At the moment we only process one type of relation - associatedStreet
1441 IF relation.tags @> ARRAY['associatedStreet'] THEN
1442 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1443 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1444 --RAISE WARNING 'node in relation %',relation;
1445 SELECT place_id from placex where osm_type = 'W'
1446 and osm_id = substring(relation.members[i],2,200)::bigint
1447 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1452 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1454 -- Note that addr:street links can only be indexed once the street itself is indexed
1455 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1456 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1457 IF address_street_word_ids IS NOT NULL THEN
1458 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1459 NEW.parent_place_id := location.place_id;
1463 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1465 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1466 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1467 IF address_street_word_ids IS NOT NULL THEN
1468 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1469 NEW.parent_place_id := location.place_id;
1473 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1475 -- Is this node part of an interpolation?
1476 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1478 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1479 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1482 NEW.parent_place_id := location.parent_place_id;
1485 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1487 -- Is this node part of a way?
1488 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1490 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.address from placex p, planet_osm_ways w
1491 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)
1493 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1495 -- Way IS a road then we are on it - that must be our road
1496 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1497 --RAISE WARNING 'node in way that is a street %',location;
1498 NEW.parent_place_id := location.place_id;
1500 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1502 -- If the way mentions a street or place address, try that for parenting.
1503 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1504 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1505 IF address_street_word_ids IS NOT NULL THEN
1506 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1507 NEW.parent_place_id := linkedplacex.place_id;
1511 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1513 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1514 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1515 IF address_street_word_ids IS NOT NULL THEN
1516 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1517 NEW.parent_place_id := linkedplacex.place_id;
1521 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1523 -- Is the WAY part of a relation
1524 IF NEW.parent_place_id IS NULL THEN
1525 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1527 -- At the moment we only process one type of relation - associatedStreet
1528 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1529 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1530 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1531 --RAISE WARNING 'node in way that is in a relation %',relation;
1532 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1533 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1539 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1545 -- Still nothing, just use the nearest road
1546 IF NEW.parent_place_id IS NULL THEN
1547 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1548 NEW.parent_place_id := location.place_id;
1551 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1554 -- If we didn't find any road fallback to standard method
1555 IF NEW.parent_place_id IS NOT NULL THEN
1557 -- Get the details of the parent road
1558 select * from search_name where place_id = NEW.parent_place_id INTO location;
1559 NEW.country_code := location.country_code;
1560 --DEBUG: RAISE WARNING 'Got parent details from search name';
1562 -- determine postcode
1563 IF NEW.rank_search > 4 THEN
1564 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1565 NEW.postcode = upper(trim(NEW.address->'postcode'));
1567 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1569 IF NEW.postcode is null THEN
1570 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1574 -- If there is no name it isn't searchable, don't bother to create a search record
1575 IF NEW.name is NULL THEN
1576 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1580 -- Merge address from parent
1581 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1582 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1584 -- Performance, it would be more acurate to do all the rest of the import
1585 -- process but it takes too long
1586 -- Just be happy with inheriting from parent road only
1588 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1589 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);
1590 --DEBUG: RAISE WARNING 'Place added to location table';
1593 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);
1594 --DEBUG: RAISE WARNING 'Place added to search table';
1601 -- ---------------------------------------------------------------------------
1603 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1605 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1607 -- see if we have any special relation members
1608 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1609 --DEBUG: RAISE WARNING 'Got relation members';
1611 IF relation_members IS NOT NULL THEN
1612 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1613 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1615 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1616 and osm_id = substring(relMember.member,2,10000)::bigint
1617 and class = 'place' order by rank_search desc limit 1 LOOP
1619 -- If we don't already have one use this as the centre point of the geometry
1620 IF NEW.centroid IS NULL THEN
1621 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1624 -- merge in the label name, re-init word vector
1625 IF NOT linkedPlacex.name IS NULL THEN
1626 NEW.name := linkedPlacex.name || NEW.name;
1627 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1630 -- merge in extra tags
1631 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1633 -- mark the linked place (excludes from search results)
1634 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1636 -- keep a note of the node id in case we need it for wikipedia in a bit
1637 linked_node_id := linkedPlacex.osm_id;
1638 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1639 --DEBUG: RAISE WARNING 'Linked label member';
1644 IF NEW.centroid IS NULL THEN
1646 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1647 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1649 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1650 and osm_id = substring(relMember.member,2,10000)::bigint
1651 and class = 'place' order by rank_search desc limit 1 LOOP
1653 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1654 -- But that can be fixed by explicitly setting the label in the data
1655 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1656 AND NEW.rank_address = linkedPlacex.rank_address THEN
1658 -- If we don't already have one use this as the centre point of the geometry
1659 IF NEW.centroid IS NULL THEN
1660 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1663 -- merge in the name, re-init word vector
1664 IF NOT linkedPlacex.name IS NULL THEN
1665 NEW.name := linkedPlacex.name || NEW.name;
1666 name_vector := make_keywords(NEW.name);
1669 -- merge in extra tags
1670 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1672 -- mark the linked place (excludes from search results)
1673 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1675 -- keep a note of the node id in case we need it for wikipedia in a bit
1676 linked_node_id := linkedPlacex.osm_id;
1677 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1678 --DEBUG: RAISE WARNING 'Linked admin_center';
1690 -- Name searches can be done for ways as well as relations
1691 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1693 -- not found one yet? how about doing a name search
1694 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1696 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1697 FOR linkedPlacex IN select placex.* from placex WHERE
1698 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1699 AND placex.rank_address = NEW.rank_address
1700 AND placex.place_id != NEW.place_id
1701 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1702 AND st_covers(NEW.geometry, placex.geometry)
1704 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1705 -- If we don't already have one use this as the centre point of the geometry
1706 IF NEW.centroid IS NULL THEN
1707 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1710 -- merge in the name, re-init word vector
1711 NEW.name := linkedPlacex.name || NEW.name;
1712 name_vector := make_keywords(NEW.name);
1714 -- merge in extra tags
1715 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1717 -- mark the linked place (excludes from search results)
1718 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1720 -- keep a note of the node id in case we need it for wikipedia in a bit
1721 linked_node_id := linkedPlacex.osm_id;
1722 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1723 --DEBUG: RAISE WARNING 'Linked named place';
1727 IF NEW.centroid IS NOT NULL THEN
1728 place_centroid := NEW.centroid;
1729 -- Place might have had only a name tag before but has now received translations
1730 -- from the linked place. Make sure a name tag for the default language exists in
1732 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1733 default_language := get_country_language_code(NEW.country_code);
1734 IF default_language IS NOT NULL THEN
1735 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1736 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1737 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1738 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1742 --DEBUG: RAISE WARNING 'Names updated from linked places';
1745 -- Use the maximum importance if a one could be computed from the linked object.
1746 IF linked_importance is not null AND
1747 (NEW.importance is null or NEW.importance < linked_importance) THEN
1748 NEW.importance = linked_importance;
1751 -- Still null? how about looking it up by the node id
1752 IF NEW.importance IS NULL THEN
1753 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1754 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;
1759 -- make sure all names are in the word table
1760 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1761 perform create_country(NEW.name, lower(NEW.country_code));
1762 --DEBUG: RAISE WARNING 'Country names updated';
1765 NEW.parent_place_id = 0;
1766 parent_place_id_rank = 0;
1769 -- convert isin to array of tokenids
1770 --DEBUG: RAISE WARNING 'Starting address search';
1771 isin_tokens := '{}'::int[];
1772 IF NEW.address IS NOT NULL THEN
1773 isin := avals(NEW.address);
1774 IF array_upper(isin, 1) IS NOT NULL THEN
1775 FOR i IN 1..array_upper(isin, 1) LOOP
1776 -- TODO further split terms with comma and semicolon
1777 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1778 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1779 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1780 isin_tokens := isin_tokens || address_street_word_id;
1783 -- merge word into address vector
1784 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1785 IF address_street_word_id IS NOT NULL THEN
1786 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1792 -- %NOTIGERDATA% IF 0 THEN
1793 -- for the USA we have an additional address table. Merge in zip codes from there too
1794 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1795 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1796 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1797 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1798 isin_tokens := isin_tokens || address_street_word_id;
1800 -- also merge in the single word version
1801 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1802 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1805 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1806 -- %NOTIGERDATA% END IF;
1808 -- RAISE WARNING 'ISIN: %', isin_tokens;
1810 -- Process area matches
1811 location_rank_search := 0;
1812 location_distance := 0;
1813 location_parent := NULL;
1814 -- added ourself as address already
1815 address_havelevel[NEW.rank_address] := true;
1816 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1818 SELECT * from getNearFeatures(NEW.partition,
1819 CASE WHEN NEW.rank_search >= 26
1820 AND NEW.rank_search < 30
1822 ELSE place_centroid END,
1823 search_maxrank, isin_tokens)
1825 IF location.rank_address != location_rank_search THEN
1826 location_rank_search := location.rank_address;
1827 IF location.isguess THEN
1828 location_distance := location.distance * 1.5;
1830 IF location.rank_address <= 12 THEN
1831 -- for county and above, if we have an area consider that exact
1832 -- (It would be nice to relax the constraint for places close to
1833 -- the boundary but we'd need the exact geometry for that. Too
1835 location_distance = 0;
1837 -- Below county level remain slightly fuzzy.
1838 location_distance := location.distance * 0.5;
1842 CONTINUE WHEN location.keywords <@ location_keywords;
1845 IF location.distance < location_distance OR NOT location.isguess THEN
1846 location_keywords := location.keywords;
1848 location_isaddress := NOT address_havelevel[location.rank_address];
1849 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1850 location_isaddress := ST_Contains(location_parent,location.centroid);
1853 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1854 -- Add it to the list of search terms
1855 IF location.rank_search > 4 THEN
1856 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1858 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1859 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1861 IF location_isaddress THEN
1862 -- add postcode if we have one
1863 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1864 IF location.postcode is not null THEN
1865 NEW.postcode = location.postcode;
1868 address_havelevel[location.rank_address] := true;
1869 IF NOT location.isguess THEN
1870 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1873 IF location.rank_address > parent_place_id_rank THEN
1874 NEW.parent_place_id = location.place_id;
1875 parent_place_id_rank = location.rank_address;
1880 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1885 --DEBUG: RAISE WARNING 'address computed';
1887 -- try using the isin value to find parent places
1888 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1889 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1890 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1891 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1893 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1895 --RAISE WARNING ' ISIN: %',location;
1897 IF location.rank_search > 4 THEN
1898 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1899 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1900 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1901 IF NEW.postcode is null AND location.postcode is not null
1902 AND NOT address_havelevel[location.rank_address] THEN
1903 NEW.postcode := location.postcode;
1906 address_havelevel[location.rank_address] := true;
1908 IF location.rank_address > parent_place_id_rank THEN
1909 NEW.parent_place_id = location.place_id;
1910 parent_place_id_rank = location.rank_address;
1919 --DEBUG: RAISE WARNING 'isin tokens processed';
1921 -- for long ways we should add search terms for the entire length
1922 IF st_length(NEW.geometry) > 0.05 THEN
1924 location_rank_search := 0;
1925 location_distance := 0;
1927 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1929 IF location.rank_address != location_rank_search THEN
1930 location_rank_search := location.rank_address;
1931 location_distance := location.distance * 1.5;
1934 IF location.rank_search > 4 AND location.distance < location_distance THEN
1936 -- Add it to the list of search terms
1937 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1938 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1939 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1946 --DEBUG: RAISE WARNING 'search terms for long ways added';
1948 IF NEW.address is not null AND NEW.address ? 'postcode'
1949 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1950 NEW.postcode := upper(trim(NEW.address->'postcode'));
1953 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1954 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1957 -- if we have a name add this to the name search table
1958 IF NEW.name IS NOT NULL THEN
1960 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1961 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);
1962 --DEBUG: RAISE WARNING 'added to location (full)';
1965 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1966 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1967 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1970 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);
1971 --DEBUG: RAISE WARNING 'added to serach name (full)';
1975 -- If we've not managed to pick up a better one - default centroid
1976 IF NEW.centroid IS NULL THEN
1977 NEW.centroid := place_centroid;
1980 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1987 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1993 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1995 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1996 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1997 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1998 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
2000 IF OLD.rank_address < 30 THEN
2002 -- mark everything linked to this place for re-indexing
2003 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
2004 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
2005 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
2007 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
2008 DELETE FROM place_addressline where address_place_id = OLD.place_id;
2010 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
2011 b := deleteRoad(OLD.partition, OLD.place_id);
2013 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
2014 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
2015 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
2016 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
2017 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
2021 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2023 IF OLD.rank_address < 26 THEN
2024 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2027 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2029 IF OLD.name is not null THEN
2030 b := deleteSearchName(OLD.partition, OLD.place_id);
2033 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2035 DELETE FROM place_addressline where place_id = OLD.place_id;
2037 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2039 -- remove from tables for special search
2040 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2041 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2043 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2046 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2054 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2060 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2062 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2063 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2064 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;
2066 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2072 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;
2074 -- interpolations are special
2075 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2076 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2085 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2090 existingplacex RECORD;
2091 existingline RECORD;
2092 existinggeometry GEOMETRY;
2093 existingplace_id BIGINT;
2098 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2099 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2100 -- filter wrong tupels
2101 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
2102 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2103 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2104 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2108 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2109 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2110 -- Have we already done this place?
2111 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;
2113 -- Get the existing place_id
2114 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2116 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2117 IF existing.osm_type IS NULL THEN
2118 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2121 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2122 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2124 -- 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)
2125 IF existingline.osm_id IS NOT NULL THEN
2126 delete from location_property_osmline where osm_id = NEW.osm_id;
2129 -- for interpolations invalidate all nodes on the line
2130 update placex p set indexed_status = 2
2131 from planet_osm_ways w
2132 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2135 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2136 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2139 IF existing.osm_type IS NULL THEN
2143 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2144 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2145 OR existing.geometry::text != NEW.geometry::text
2150 address = NEW.address,
2151 extratags = NEW.extratags,
2152 admin_level = NEW.admin_level,
2153 geometry = NEW.geometry
2154 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2159 ELSE -- insert to placex
2161 -- Patch in additional country names
2162 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2163 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2164 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2165 IF existing.name IS NOT NULL THEN
2166 NEW.name = existing.name || NEW.name;
2170 -- Have we already done this place?
2171 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;
2173 -- Get the existing place_id
2174 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;
2176 -- Handle a place changing type by removing the old data
2177 -- My generated 'place' types are causing havok because they overlap with real keys
2178 -- TODO: move them to their own special purpose key/class to avoid collisions
2179 IF existing.osm_type IS NULL THEN
2180 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2183 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2184 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2187 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2188 AND st_area(existing.geometry) > 0.02
2189 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2190 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2192 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2193 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2194 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2198 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2199 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2201 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2202 IF existingplacex.osm_type IS NULL OR
2203 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2206 IF existingplacex.osm_type IS NOT NULL THEN
2207 -- sanity check: ignore admin_level changes on places with too many active children
2208 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2209 --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;
2210 --LIMIT INDEXING: IF i > 100000 THEN
2211 --LIMIT INDEXING: RETURN null;
2212 --LIMIT INDEXING: END IF;
2215 IF existing.osm_type IS NOT NULL THEN
2216 -- pathological case caused by the triggerless copy into place during initial import
2217 -- force delete even for large areas, it will be reinserted later
2218 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;
2219 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2222 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2223 insert into placex (osm_type, osm_id, class, type, name,
2224 admin_level, address, extratags, geometry)
2225 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2226 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2228 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2233 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2234 IF existing.geometry::text != NEW.geometry::text
2235 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2236 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2239 -- Get the version of the geometry actually used (in placex table)
2240 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;
2242 -- Performance limit
2243 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2245 -- 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
2246 update placex set indexed_status = 2 where indexed_status = 0 and
2247 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2248 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2249 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2251 update placex set indexed_status = 2 where indexed_status = 0 and
2252 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2253 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2254 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2261 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2262 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2263 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2264 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2265 OR existing.geometry::text != NEW.geometry::text
2270 address = NEW.address,
2271 extratags = NEW.extratags,
2272 admin_level = NEW.admin_level,
2273 geometry = NEW.geometry
2274 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2277 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2278 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2279 -- postcode was deleted, no longer retain in placex
2280 DELETE FROM placex where place_id = existingplacex.place_id;
2284 NEW.name := hstore('ref', NEW.address->'postcode');
2287 IF NEW.class in ('boundary')
2288 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2289 DELETE FROM placex where place_id = existingplacex.place_id;
2295 address = NEW.address,
2296 parent_place_id = null,
2297 extratags = NEW.extratags,
2298 admin_level = NEW.admin_level,
2300 geometry = NEW.geometry
2301 where place_id = existingplacex.place_id;
2303 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2304 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2305 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2306 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2307 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);
2310 -- linked places should get potential new naming and addresses
2311 IF existingplacex.linked_place_id is not NULL THEN
2314 extratags = p.extratags,
2317 where x.place_id = existingplacex.linked_place_id
2318 and x.indexed_status = 0
2319 and x.osm_type = p.osm_type
2320 and x.osm_id = p.osm_id
2321 and x.class = p.class;
2326 -- Abort the add (we modified the existing place instead)
2331 $$ LANGUAGE plpgsql;
2334 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2339 IF name is null THEN
2343 FOR j IN 1..array_upper(languagepref,1) LOOP
2344 IF name ? languagepref[j] THEN
2345 result := trim(name->languagepref[j]);
2346 IF result != '' THEN
2352 -- anything will do as a fallback - just take the first name type thing there is
2353 RETURN trim((avals(name))[1]);
2356 LANGUAGE plpgsql IMMUTABLE;
2358 --housenumber only needed for tiger data
2359 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2371 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2372 currresult := trim(get_name_by_language(location.name, languagepref));
2373 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2374 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2375 prevresult := currresult;
2379 RETURN array_to_string(result,', ');
2384 DROP TYPE IF EXISTS addressline CASCADE;
2385 create type addressline as (
2392 admin_level INTEGER,
2395 rank_address INTEGER,
2399 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2402 for_place_id BIGINT;
2407 countrylocation RECORD;
2408 searchcountrycode varchar(2);
2409 searchhousenumber TEXT;
2410 searchhousename HSTORE;
2411 searchrankaddress INTEGER;
2412 searchpostcode TEXT;
2418 -- first query osmline (interpolation lines)
2419 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2420 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2421 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2422 IF for_place_id IS NOT NULL THEN
2423 searchhousenumber = in_housenumber::text;
2426 --then query tiger data
2427 -- %NOTIGERDATA% IF 0 THEN
2428 IF for_place_id IS NULL THEN
2429 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2430 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2431 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2432 IF for_place_id IS NOT NULL THEN
2433 searchhousenumber = in_housenumber::text;
2436 -- %NOTIGERDATA% END IF;
2438 -- %NOAUXDATA% IF 0 THEN
2439 IF for_place_id IS NULL THEN
2440 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2441 WHERE place_id = in_place_id
2442 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2444 -- %NOAUXDATA% END IF;
2447 IF for_place_id IS NULL THEN
2448 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2449 FROM location_postcode
2450 WHERE place_id = in_place_id
2451 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2454 IF for_place_id IS NULL THEN
2455 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2456 WHERE place_id = in_place_id and rank_search > 27
2457 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2460 IF for_place_id IS NULL THEN
2461 select coalesce(linked_place_id, place_id), country_code,
2462 housenumber, rank_search, postcode, null
2463 from placex where place_id = in_place_id
2464 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2467 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2470 hadcountry := false;
2472 select placex.place_id, osm_type, osm_id, name,
2473 class, type, admin_level, true as isaddress,
2474 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2475 0 as distance, country_code, postcode
2477 where place_id = for_place_id
2479 --RAISE WARNING '%',location;
2480 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2481 searchcountrycode := location.country_code;
2483 IF location.type in ('postcode', 'postal_code') THEN
2484 location.isaddress := FALSE;
2485 ELSEIF location.rank_address = 4 THEN
2488 IF location.rank_address < 4 AND NOT hadcountry THEN
2489 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2490 IF countryname IS NOT NULL THEN
2491 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2492 RETURN NEXT countrylocation;
2495 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2496 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2497 location.distance)::addressline;
2498 RETURN NEXT countrylocation;
2499 found := location.rank_address;
2503 select placex.place_id, osm_type, osm_id, name,
2504 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2505 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2506 admin_level, fromarea, isaddress,
2507 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,
2508 distance,country_code,postcode
2509 from place_addressline join placex on (address_place_id = placex.place_id)
2510 where place_addressline.place_id = for_place_id
2511 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2512 and address_place_id != for_place_id
2513 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2514 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2516 --RAISE WARNING '%',location;
2517 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2518 searchcountrycode := location.country_code;
2520 IF location.type in ('postcode', 'postal_code') THEN
2521 location.isaddress := FALSE;
2523 IF location.rank_address = 4 AND location.isaddress THEN
2526 IF location.rank_address < 4 AND NOT hadcountry THEN
2527 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2528 IF countryname IS NOT NULL THEN
2529 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2530 RETURN NEXT countrylocation;
2533 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2534 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2535 location.distance)::addressline;
2536 RETURN NEXT countrylocation;
2537 found := location.rank_address;
2541 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2542 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2543 IF countryname IS NOT NULL THEN
2544 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2545 RETURN NEXT location;
2549 IF searchcountrycode IS NOT NULL THEN
2550 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2551 RETURN NEXT location;
2554 IF searchhousename IS NOT NULL THEN
2555 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2556 RETURN NEXT location;
2559 IF searchhousenumber IS NOT NULL THEN
2560 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2561 RETURN NEXT location;
2564 IF searchpostcode IS NOT NULL THEN
2565 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2566 RETURN NEXT location;
2575 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2581 ELSEIF rank < 4 THEN
2583 ELSEIF rank < 8 THEN
2585 ELSEIF rank < 12 THEN
2587 ELSEIF rank < 16 THEN
2589 ELSEIF rank = 16 THEN
2591 ELSEIF rank = 17 THEN
2592 RETURN 'Town / Island';
2593 ELSEIF rank = 18 THEN
2594 RETURN 'Village / Hamlet';
2595 ELSEIF rank = 20 THEN
2597 ELSEIF rank = 21 THEN
2598 RETURN 'Postcode Area';
2599 ELSEIF rank = 22 THEN
2600 RETURN 'Croft / Farm / Locality / Islet';
2601 ELSEIF rank = 23 THEN
2602 RETURN 'Postcode Area';
2603 ELSEIF rank = 25 THEN
2604 RETURN 'Postcode Point';
2605 ELSEIF rank = 26 THEN
2606 RETURN 'Street / Major Landmark';
2607 ELSEIF rank = 27 THEN
2608 RETURN 'Minory Street / Path';
2609 ELSEIF rank = 28 THEN
2610 RETURN 'House / Building';
2612 RETURN 'Other: '||rank;
2619 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2625 ELSEIF rank < 2 THEN
2627 ELSEIF rank < 4 THEN
2629 ELSEIF rank = 5 THEN
2631 ELSEIF rank < 8 THEN
2633 ELSEIF rank < 12 THEN
2635 ELSEIF rank < 16 THEN
2637 ELSEIF rank = 16 THEN
2639 ELSEIF rank = 17 THEN
2640 RETURN 'Town / Village / Hamlet';
2641 ELSEIF rank = 20 THEN
2643 ELSEIF rank = 21 THEN
2644 RETURN 'Postcode Area';
2645 ELSEIF rank = 22 THEN
2646 RETURN 'Croft / Farm / Locality / Islet';
2647 ELSEIF rank = 23 THEN
2648 RETURN 'Postcode Area';
2649 ELSEIF rank = 25 THEN
2650 RETURN 'Postcode Point';
2651 ELSEIF rank = 26 THEN
2652 RETURN 'Street / Major Landmark';
2653 ELSEIF rank = 27 THEN
2654 RETURN 'Minory Street / Path';
2655 ELSEIF rank = 28 THEN
2656 RETURN 'House / Building';
2658 RETURN 'Other: '||rank;
2665 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2666 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2671 place_centroid GEOMETRY;
2672 out_partition INTEGER;
2673 out_parent_place_id BIGINT;
2675 address_street_word_id INTEGER;
2680 place_centroid := ST_Centroid(pointgeo);
2681 out_partition := get_partition(in_countrycode);
2682 out_parent_place_id := null;
2684 address_street_word_id := get_name_id(make_standard_name(in_street));
2685 IF address_street_word_id IS NOT NULL THEN
2686 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2687 out_parent_place_id := location.place_id;
2691 IF out_parent_place_id IS NULL THEN
2692 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2693 out_parent_place_id := location.place_id;
2697 out_postcode := in_postcode;
2698 IF out_postcode IS NULL THEN
2699 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2701 -- XXX look into postcode table
2704 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2705 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2706 newpoints := newpoints + 1;
2713 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2720 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2721 IF members[i+1] = member THEN
2722 result := result || members[i];
2731 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2737 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2738 IF members[i+1] = ANY(memberLabels) THEN
2739 RETURN NEXT members[i];
2748 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2749 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2751 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2752 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
2753 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2754 ), '') AS bytea), 'UTF8');
2756 LANGUAGE SQL IMMUTABLE STRICT;
2758 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2762 RETURN decode_url_part(p);
2764 WHEN others THEN return null;
2767 LANGUAGE plpgsql IMMUTABLE;
2769 DROP TYPE wikipedia_article_match CASCADE;
2770 create type wikipedia_article_match as (
2776 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2782 wiki_article_title TEXT;
2783 wiki_article_language TEXT;
2784 result wikipedia_article_match;
2786 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'];
2788 WHILE langs[i] IS NOT NULL LOOP
2789 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2790 IF wiki_article is not null THEN
2791 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2792 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2793 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2794 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2795 wiki_article := replace(wiki_article,' ','_');
2796 IF strpos(wiki_article, ':') IN (3,4) THEN
2797 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2798 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2800 wiki_article_title := trim(wiki_article);
2801 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;
2804 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2805 from wikipedia_article
2806 where language = wiki_article_language and
2807 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2809 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2810 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2811 where wikipedia_redirect.language = wiki_article_language and
2812 (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'\\',''))
2813 order by importance desc limit 1 INTO result;
2815 IF result.language is not null THEN
2826 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2827 RETURNS SETOF GEOMETRY
2841 remainingdepth INTEGER;
2846 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2848 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2849 RETURN NEXT geometry;
2853 remainingdepth := maxdepth - 1;
2854 area := ST_AREA(geometry);
2855 IF remainingdepth < 1 OR area < maxarea THEN
2856 RETURN NEXT geometry;
2860 xmin := st_xmin(geometry);
2861 xmax := st_xmax(geometry);
2862 ymin := st_ymin(geometry);
2863 ymax := st_ymax(geometry);
2864 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2866 -- if the geometry completely covers the box don't bother to slice any more
2867 IF ST_AREA(secbox) = area THEN
2868 RETURN NEXT geometry;
2872 xmid := (xmin+xmax)/2;
2873 ymid := (ymin+ymax)/2;
2876 FOR seg IN 1..4 LOOP
2879 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2882 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2885 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2888 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2891 IF st_intersects(geometry, secbox) THEN
2892 secgeo := st_intersection(geometry, secbox);
2893 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2894 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2895 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2897 RETURN NEXT geo.geom;
2909 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2910 RETURNS SETOF GEOMETRY
2915 -- 10000000000 is ~~ 1x1 degree
2916 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2917 RETURN NEXT geo.geom;
2925 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2929 osmtype character(1);
2933 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2934 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2935 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2936 -- force delete from place/placex by making it a very small geometry
2937 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;
2938 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2945 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2953 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2954 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2955 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2956 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2957 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2958 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2959 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
2960 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2961 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'));
2967 ELSEIF rank < 18 THEN
2969 ELSEIF rank < 20 THEN
2971 ELSEIF rank = 21 THEN
2973 ELSEIF rank < 24 THEN
2975 ELSEIF rank < 26 THEN
2976 diameter := 0.002; -- 100 to 200 meters
2977 ELSEIF rank < 28 THEN
2978 diameter := 0.001; -- 50 to 100 meters
2980 IF diameter > 0 THEN
2982 -- roads may cause reparenting for >27 rank places
2983 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2984 ELSEIF rank >= 16 THEN
2985 -- up to rank 16, street-less addresses may need reparenting
2986 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');
2988 -- for all other places the search terms may change as well
2989 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);