1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
261 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
269 IF country_code = 'gb' THEN
270 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
273 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
276 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
281 ELSEIF country_code = 'sg' THEN
282 IF postcode ~ '^([0-9]{6})$' THEN
287 ELSEIF country_code = 'de' THEN
288 IF postcode ~ '^([0-9]{5})$' THEN
294 -- Guess at the postcode format and coverage (!)
295 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
299 -- Does it look splitable into and area and local code?
300 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
302 IF part IS NOT NULL THEN
305 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
314 LANGUAGE plpgsql IMMUTABLE;
316 -- Find the nearest artificial postcode for the given geometry.
317 -- TODO For areas there should not be more than two inside the geometry.
318 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
324 SELECT postcode FROM location_postcode
325 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
326 AND location_postcode.country_code = country
327 ORDER BY ST_Distance(geom, location_postcode.geometry)
330 RETURN item.postcode;
339 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
348 FOR item IN SELECT (each(src)).* LOOP
350 s := make_standard_name(item.value);
351 w := getorcreate_country(s, lookup_country_code);
353 words := regexp_split_to_array(item.value, E'[,;()]');
354 IF array_upper(words, 1) != 1 THEN
355 FOR j IN 1..array_upper(words, 1) LOOP
356 s := make_standard_name(words[j]);
358 w := getorcreate_country(s, lookup_country_code);
367 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
377 result := '{}'::INTEGER[];
379 FOR item IN SELECT (each(src)).* LOOP
381 s := make_standard_name(item.value);
383 w := getorcreate_name_id(s, item.value);
385 IF not(ARRAY[w] <@ result) THEN
386 result := result || w;
389 w := getorcreate_word_id(s);
391 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
392 result := result || w;
395 words := string_to_array(s, ' ');
396 IF array_upper(words, 1) IS NOT NULL THEN
397 FOR j IN 1..array_upper(words, 1) LOOP
398 IF (words[j] != '') THEN
399 w = getorcreate_word_id(words[j]);
400 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
401 result := result || w;
407 words := regexp_split_to_array(item.value, E'[,;()]');
408 IF array_upper(words, 1) != 1 THEN
409 FOR j IN 1..array_upper(words, 1) LOOP
410 s := make_standard_name(words[j]);
412 w := getorcreate_word_id(s);
413 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
414 result := result || w;
420 s := regexp_replace(item.value, '市$', '');
421 IF s != item.value THEN
422 s := make_standard_name(s);
424 w := getorcreate_name_id(s, item.value);
425 IF NOT (ARRAY[w] <@ result) THEN
426 result := result || w;
436 LANGUAGE plpgsql IMMUTABLE;
438 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
448 result := '{}'::INTEGER[];
450 s := make_standard_name(src);
451 w := getorcreate_name_id(s, src);
453 IF NOT (ARRAY[w] <@ result) THEN
454 result := result || w;
457 w := getorcreate_word_id(s);
459 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
460 result := result || w;
463 words := string_to_array(s, ' ');
464 IF array_upper(words, 1) IS NOT NULL THEN
465 FOR j IN 1..array_upper(words, 1) LOOP
466 IF (words[j] != '') THEN
467 w = getorcreate_word_id(words[j]);
468 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
469 result := result || w;
475 words := regexp_split_to_array(src, E'[,;()]');
476 IF array_upper(words, 1) != 1 THEN
477 FOR j IN 1..array_upper(words, 1) LOOP
478 s := make_standard_name(words[j]);
480 w := getorcreate_word_id(s);
481 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
482 result := result || w;
488 s := regexp_replace(src, '市$', '');
490 s := make_standard_name(s);
492 w := getorcreate_name_id(s, src);
493 IF NOT (ARRAY[w] <@ result) THEN
494 result := result || w;
502 LANGUAGE plpgsql IMMUTABLE;
504 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
507 place_centre GEOMETRY;
510 place_centre := ST_PointOnSurface(place);
512 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
514 -- Try for a OSM polygon
515 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
517 RETURN nearcountry.country_code;
520 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
522 -- Try for OSM fallback data
523 -- The order is to deal with places like HongKong that are 'states' within another polygon
524 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
526 RETURN nearcountry.country_code;
529 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
531 -- Natural earth data
532 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
534 RETURN nearcountry.country_code;
537 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
540 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
542 RETURN nearcountry.country_code;
545 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
547 -- Natural earth data
548 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
550 RETURN nearcountry.country_code;
556 LANGUAGE plpgsql IMMUTABLE;
558 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
563 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
565 RETURN lower(nearcountry.country_default_language_code);
570 LANGUAGE plpgsql IMMUTABLE;
572 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
577 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
579 RETURN lower(nearcountry.country_default_language_codes);
584 LANGUAGE plpgsql IMMUTABLE;
586 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
591 FOR nearcountry IN select partition from country_name where country_code = in_country_code
593 RETURN nearcountry.partition;
598 LANGUAGE plpgsql IMMUTABLE;
600 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
604 DELETE FROM location_area where place_id = OLD_place_id;
605 -- TODO:location_area
611 CREATE OR REPLACE FUNCTION add_location(
613 country_code varchar(2),
617 rank_address INTEGER,
633 IF rank_search > 25 THEN
634 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
637 x := deleteLocationArea(partition, place_id, rank_search);
639 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
641 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
642 postcode := upper(trim (in_postcode));
645 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
646 centroid := ST_Centroid(geometry);
648 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
649 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
655 IF rank_address = 0 THEN
657 ELSEIF rank_search <= 14 THEN
659 ELSEIF rank_search <= 15 THEN
661 ELSEIF rank_search <= 16 THEN
663 ELSEIF rank_search <= 17 THEN
665 ELSEIF rank_search <= 21 THEN
667 ELSEIF rank_search = 25 THEN
671 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
673 secgeo := ST_Buffer(geometry, diameter);
674 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
684 -- find the parent road of the cut road parts
685 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
686 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
691 parent_place_id BIGINT;
692 address_street_word_ids INTEGER[];
698 addr_street = street;
701 IF addr_street is null and addr_place is null THEN
702 select nodes from planet_osm_ways where id = wayid INTO waynodes;
703 FOR location IN SELECT placex.address from placex
704 where osm_type = 'N' and osm_id = ANY(waynodes)
705 and placex.address is not null
706 and (placex.address ? 'street' or placex.address ? 'place')
707 and indexed_status < 100
709 addr_street = location.address->'street';
710 addr_place = location.address->'place';
714 IF addr_street IS NOT NULL THEN
715 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
716 IF address_street_word_ids IS NOT NULL THEN
717 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
718 parent_place_id := location.place_id;
723 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
724 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
725 IF address_street_word_ids IS NOT NULL THEN
726 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
727 parent_place_id := location.place_id;
732 IF parent_place_id is null THEN
733 FOR location IN SELECT place_id FROM placex
734 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
735 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
736 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
737 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
739 parent_place_id := location.place_id;
743 IF parent_place_id is null THEN
747 RETURN parent_place_id;
753 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
756 NEW.place_id := nextval('seq_place');
757 NEW.indexed_date := now();
759 IF NEW.indexed_status IS NULL THEN
760 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
761 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
762 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
766 NEW.indexed_status := 1; --STATUS_NEW
767 NEW.country_code := lower(get_country_code(NEW.linegeo));
769 NEW.partition := get_partition(NEW.country_code);
770 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
779 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
785 country_code VARCHAR(2);
786 default_language VARCHAR(10);
791 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
793 NEW.place_id := nextval('seq_place');
794 NEW.indexed_status := 1; --STATUS_NEW
796 NEW.country_code := lower(get_country_code(NEW.geometry));
798 NEW.partition := get_partition(NEW.country_code);
799 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
801 -- copy 'name' to or from the default language (if there is a default language)
802 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
803 default_language := get_country_language_code(NEW.country_code);
804 IF default_language IS NOT NULL THEN
805 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
806 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
807 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
808 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
813 IF NEW.osm_type = 'X' THEN
814 -- E'X'ternal records should already be in the right format so do nothing
816 NEW.rank_search := 30;
817 NEW.rank_address := NEW.rank_search;
819 -- By doing in postgres we have the country available to us - currently only used for postcode
820 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
822 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
823 -- most likely just a part of a multipolygon postcode boundary, throw it away
827 NEW.name := hstore('ref', NEW.postcode);
829 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
830 INTO NEW.rank_search, NEW.rank_address;
832 ELSEIF NEW.class = 'place' THEN
833 IF NEW.type in ('continent') THEN
834 NEW.rank_search := 2;
835 NEW.rank_address := NEW.rank_search;
836 NEW.country_code := NULL;
837 ELSEIF NEW.type in ('sea') THEN
838 NEW.rank_search := 2;
839 NEW.rank_address := 0;
840 NEW.country_code := NULL;
841 ELSEIF NEW.type in ('country') THEN
842 NEW.rank_search := 4;
843 NEW.rank_address := NEW.rank_search;
844 ELSEIF NEW.type in ('state') THEN
845 NEW.rank_search := 8;
846 NEW.rank_address := NEW.rank_search;
847 ELSEIF NEW.type in ('region') THEN
848 NEW.rank_search := 18; -- dropped from previous value of 10
849 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
850 ELSEIF NEW.type in ('county') THEN
851 NEW.rank_search := 12;
852 NEW.rank_address := NEW.rank_search;
853 ELSEIF NEW.type in ('city') THEN
854 NEW.rank_search := 16;
855 NEW.rank_address := NEW.rank_search;
856 ELSEIF NEW.type in ('island') THEN
857 NEW.rank_search := 17;
858 NEW.rank_address := 0;
859 ELSEIF NEW.type in ('town') THEN
860 NEW.rank_search := 18;
861 NEW.rank_address := 16;
862 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
863 NEW.rank_search := 19;
864 NEW.rank_address := 16;
865 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
866 NEW.rank_search := 20;
867 NEW.rank_address := NEW.rank_search;
868 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
869 NEW.rank_search := 20;
870 NEW.rank_address := 0;
871 -- Irish townlands, tagged as place=locality and locality=townland
872 IF (NEW.extratags -> 'locality') = 'townland' THEN
873 NEW.rank_address := 20;
875 ELSEIF NEW.type in ('neighbourhood') THEN
876 NEW.rank_search := 22;
877 NEW.rank_address := 22;
878 ELSEIF NEW.type in ('house','building') THEN
879 NEW.rank_search := 30;
880 NEW.rank_address := NEW.rank_search;
881 ELSEIF NEW.type in ('houses') THEN
882 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
883 NEW.rank_search := 28;
884 NEW.rank_address := 0;
887 ELSEIF NEW.class = 'boundary' THEN
888 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
889 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
892 NEW.rank_search := NEW.admin_level * 2;
893 IF NEW.type = 'administrative' THEN
894 NEW.rank_address := NEW.rank_search;
896 NEW.rank_address := 0;
898 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
899 NEW.rank_search := 22;
900 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
901 NEW.rank_address := NEW.rank_search;
903 NEW.rank_address := 0;
905 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
906 NEW.rank_search := 18;
907 NEW.rank_address := 0;
908 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
909 NEW.rank_search := 4;
910 NEW.rank_address := NEW.rank_search;
911 -- any feature more than 5 square miles is probably worth indexing
912 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
913 NEW.rank_search := 22;
914 NEW.rank_address := 0;
915 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
917 ELSEIF NEW.class = 'waterway' THEN
918 IF NEW.osm_type = 'R' THEN
919 NEW.rank_search := 16;
921 NEW.rank_search := 17;
923 NEW.rank_address := 0;
924 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
925 NEW.rank_search := 27;
926 NEW.rank_address := NEW.rank_search;
927 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
928 NEW.rank_search := 26;
929 NEW.rank_address := NEW.rank_search;
930 ELSEIF NEW.class = 'mountain_pass' THEN
931 NEW.rank_search := 20;
932 NEW.rank_address := 0;
937 IF NEW.rank_search > 30 THEN
938 NEW.rank_search := 30;
941 IF NEW.rank_address > 30 THEN
942 NEW.rank_address := 30;
945 IF (NEW.extratags -> 'capital') = 'yes' THEN
946 NEW.rank_search := NEW.rank_search - 1;
949 -- a country code make no sense below rank 4 (country)
950 IF NEW.rank_search < 4 THEN
951 NEW.country_code := NULL;
954 -- Block import below rank 22
955 -- IF NEW.rank_search > 22 THEN
959 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
961 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
963 IF NEW.rank_address > 0 THEN
964 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
965 -- Performance: We just can't handle re-indexing for country level changes
966 IF st_area(NEW.geometry) < 1 THEN
967 -- mark items within the geometry for re-indexing
968 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
970 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
971 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
972 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
973 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
974 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
977 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
979 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
980 IF NEW.type='postcode' THEN
982 ELSEIF NEW.rank_search < 16 THEN
984 ELSEIF NEW.rank_search < 18 THEN
986 ELSEIF NEW.rank_search < 20 THEN
988 ELSEIF NEW.rank_search = 21 THEN
990 ELSEIF NEW.rank_search < 24 THEN
992 ELSEIF NEW.rank_search < 26 THEN
993 diameter := 0.002; -- 100 to 200 meters
994 ELSEIF NEW.rank_search < 28 THEN
995 diameter := 0.001; -- 50 to 100 meters
998 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
999 IF NEW.rank_search >= 26 THEN
1000 -- roads may cause reparenting for >27 rank places
1001 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1002 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1003 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1004 ELSEIF NEW.rank_search >= 16 THEN
1005 -- up to rank 16, street-less addresses may need reparenting
1006 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or address ? 'place');
1008 -- for all other places the search terms may change as well
1009 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null);
1016 -- add to tables for special search
1017 -- Note: won't work on initial import because the classtype tables
1018 -- do not yet exist. It won't hurt either.
1019 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1020 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1022 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1023 USING NEW.place_id, ST_Centroid(NEW.geometry);
1032 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1036 place_centroid GEOMETRY;
1040 startnumber INTEGER;
1045 sectiongeo GEOMETRY;
1046 interpol_postcode TEXT;
1050 IF OLD.indexed_status = 100 THEN
1051 delete from location_property_osmline where place_id = OLD.place_id;
1055 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1059 NEW.interpolationtype = NEW.address->'interpolation';
1061 place_centroid := ST_PointOnSurface(NEW.linegeo);
1062 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1063 NEW.address->'place',
1064 NEW.partition, place_centroid, NEW.linegeo);
1066 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1067 interpol_postcode := NEW.address->'postcode';
1068 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1070 interpol_postcode := NULL;
1073 -- if the line was newly inserted, split the line as necessary
1074 IF OLD.indexed_status = 1 THEN
1075 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1077 IF array_upper(waynodes, 1) IS NULL THEN
1081 linegeo := NEW.linegeo;
1082 startnumber := NULL;
1084 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1086 select osm_id, address, geometry
1087 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1088 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1089 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1090 IF nextnode.osm_id IS NOT NULL THEN
1091 --RAISE NOTICE 'place_id is not null';
1092 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1093 -- Make sure that the point is actually on the line. That might
1094 -- be a bit paranoid but ensures that the algorithm still works
1095 -- should osm2pgsql attempt to repair geometries.
1096 splitline := split_line_on_node(linegeo, nextnode.geometry);
1097 sectiongeo := ST_GeometryN(splitline, 1);
1098 linegeo := ST_GeometryN(splitline, 2);
1100 sectiongeo = linegeo;
1102 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1104 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1105 AND startnumber != endnumber
1106 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1108 IF (startnumber > endnumber) THEN
1109 housenum := endnumber;
1110 endnumber := startnumber;
1111 startnumber := housenum;
1112 sectiongeo := ST_Reverse(sectiongeo);
1115 -- determine postcode
1116 postcode := coalesce(interpol_postcode,
1117 prevnode.address->'postcode',
1118 nextnode.address->'postcode',
1121 IF postcode is NULL THEN
1122 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1124 IF postcode is NULL THEN
1125 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1128 IF NEW.startnumber IS NULL THEN
1129 NEW.startnumber := startnumber;
1130 NEW.endnumber := endnumber;
1131 NEW.linegeo := sectiongeo;
1132 NEW.postcode := postcode;
1134 insert into location_property_osmline
1135 (linegeo, partition, osm_id, parent_place_id,
1136 startnumber, endnumber, interpolationtype,
1137 address, postcode, country_code,
1138 geometry_sector, indexed_status)
1139 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1140 startnumber, endnumber, NEW.interpolationtype,
1141 NEW.address, postcode,
1142 NEW.country_code, NEW.geometry_sector, 0);
1146 -- early break if we are out of line string,
1147 -- might happen when a line string loops back on itself
1148 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1152 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1153 prevnode := nextnode;
1158 -- marking descendants for reparenting is not needed, because there are
1159 -- actually no descendants for interpolation lines
1165 -- Trigger for updates of location_postcode
1167 -- Computes the parent object the postcode most likely refers to.
1168 -- This will be the place that determines the address displayed when
1169 -- searching for this postcode.
1170 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1177 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1181 NEW.indexed_date = now();
1183 partition := get_partition(NEW.country_code);
1185 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1186 INTO NEW.rank_search, NEW.rank_address;
1188 NEW.parent_place_id = 0;
1191 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1192 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1194 NEW.parent_place_id = location.place_id;
1202 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1207 place_centroid GEOMETRY;
1209 search_maxdistance FLOAT[];
1210 search_mindistance FLOAT[];
1211 address_havelevel BOOLEAN[];
1218 relation_members TEXT[];
1220 linkedplacex RECORD;
1221 search_diameter FLOAT;
1222 search_prevdiameter FLOAT;
1223 search_maxrank INTEGER;
1224 address_maxrank INTEGER;
1225 address_street_word_id INTEGER;
1226 address_street_word_ids INTEGER[];
1227 parent_place_id_rank BIGINT;
1235 location_rank_search INTEGER;
1236 location_distance FLOAT;
1237 location_parent GEOMETRY;
1238 location_isaddress BOOLEAN;
1239 location_keywords INTEGER[];
1241 default_language TEXT;
1242 name_vector INTEGER[];
1243 nameaddress_vector INTEGER[];
1245 linked_node_id BIGINT;
1246 linked_importance FLOAT;
1247 linked_wikipedia TEXT;
1252 IF OLD.indexed_status = 100 THEN
1253 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1254 delete from placex where place_id = OLD.place_id;
1258 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1262 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1264 NEW.indexed_date = now();
1266 result := deleteSearchName(NEW.partition, NEW.place_id);
1267 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1268 result := deleteRoad(NEW.partition, NEW.place_id);
1269 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1270 UPDATE placex set linked_place_id = null, indexed_status = 2
1271 where linked_place_id = NEW.place_id;
1272 -- update not necessary for osmline, cause linked_place_id does not exist
1274 IF NEW.linked_place_id is not null THEN
1275 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1279 --DEBUG: RAISE WARNING 'Copy over address tags';
1280 IF NEW.address is not NULL THEN
1281 IF NEW.address ? 'conscriptionnumber' THEN
1282 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1283 IF NEW.address ? 'streetnumber' THEN
1284 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1285 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1287 NEW.housenumber := NEW.address->'conscriptionnumber';
1289 ELSEIF NEW.address ? 'streetnumber' THEN
1290 NEW.housenumber := NEW.address->'streetnumber';
1291 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1292 ELSEIF NEW.address ? 'housenumber' THEN
1293 NEW.housenumber := NEW.address->'housenumber';
1294 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1297 addr_street = NEW.address->'street';
1298 addr_place = NEW.address->'place';
1300 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1301 i := getorcreate_postcode_id(NEW.address->'postcode');
1305 -- Speed up searches - just use the centroid of the feature
1306 -- cheaper but less acurate
1307 place_centroid := ST_PointOnSurface(NEW.geometry);
1308 NEW.centroid := null;
1309 NEW.postcode := null;
1310 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1312 -- recalculate country and partition
1313 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1314 -- for countries, believe the mapped country code,
1315 -- so that we remain in the right partition if the boundaries
1317 NEW.country_code := lower(NEW.address->'country');
1318 NEW.partition := get_partition(lower(NEW.country_code));
1319 IF NEW.partition = 0 THEN
1320 NEW.country_code := lower(get_country_code(place_centroid));
1321 NEW.partition := get_partition(NEW.country_code);
1324 IF NEW.rank_search >= 4 THEN
1325 NEW.country_code := lower(get_country_code(place_centroid));
1327 NEW.country_code := NULL;
1329 NEW.partition := get_partition(NEW.country_code);
1331 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1333 -- waterway ways are linked when they are part of a relation and have the same class/type
1334 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1335 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1337 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1338 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1339 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1340 FOR linked_node_id IN SELECT place_id FROM placex
1341 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1342 and class = NEW.class and type = NEW.type
1343 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1345 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1350 --DEBUG: RAISE WARNING 'Waterway processed';
1353 -- Adding ourselves to the list simplifies address calculations later
1354 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1355 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1357 -- What level are we searching from
1358 search_maxrank := NEW.rank_search;
1360 -- Thought this wasn't needed but when we add new languages to the country_name table
1361 -- we need to update the existing names
1362 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1363 default_language := get_country_language_code(NEW.country_code);
1364 IF default_language IS NOT NULL THEN
1365 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1366 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1367 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1368 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1372 --DEBUG: RAISE WARNING 'Local names updated';
1374 -- Initialise the name vector using our name
1375 name_vector := make_keywords(NEW.name);
1376 nameaddress_vector := '{}'::int[];
1379 address_havelevel[i] := false;
1382 NEW.importance := null;
1383 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1384 IF NEW.importance IS NULL THEN
1385 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;
1388 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1390 -- ---------------------------------------------------------------------------
1391 -- For low level elements we inherit from our parent road
1392 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1394 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1396 -- We won't get a better centroid, besides these places are too small to care
1397 NEW.centroid := place_centroid;
1399 NEW.parent_place_id := null;
1401 -- if we have a POI and there is no address information,
1402 -- see if we can get it from a surrounding building
1403 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1404 AND NEW.housenumber IS NULL THEN
1405 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1406 and address is not null
1407 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1408 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1411 NEW.housenumber := location.address->'housenumber';
1412 addr_street := location.address->'street';
1413 addr_place := location.address->'place';
1414 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1418 -- We have to find our parent road.
1419 -- Copy data from linked items (points on ways, addr:street links, relations)
1421 -- Is this object part of a relation?
1422 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1424 -- At the moment we only process one type of relation - associatedStreet
1425 IF relation.tags @> ARRAY['associatedStreet'] THEN
1426 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1427 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1428 --RAISE WARNING 'node in relation %',relation;
1429 SELECT place_id from placex where osm_type = 'W'
1430 and osm_id = substring(relation.members[i],2,200)::bigint
1431 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1436 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1438 -- Note that addr:street links can only be indexed once the street itself is indexed
1439 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1440 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1441 IF address_street_word_ids IS NOT NULL THEN
1442 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1443 NEW.parent_place_id := location.place_id;
1447 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1449 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1450 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1451 IF address_street_word_ids IS NOT NULL THEN
1452 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1453 NEW.parent_place_id := location.place_id;
1457 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1459 -- Is this node part of an interpolation?
1460 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1462 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1463 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1466 NEW.parent_place_id := location.parent_place_id;
1469 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1471 -- Is this node part of a way?
1472 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1474 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
1475 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)
1477 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1479 -- Way IS a road then we are on it - that must be our road
1480 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1481 --RAISE WARNING 'node in way that is a street %',location;
1482 NEW.parent_place_id := location.place_id;
1484 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1486 -- If the way mentions a street or place address, try that for parenting.
1487 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1488 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1489 IF address_street_word_ids IS NOT NULL THEN
1490 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1491 NEW.parent_place_id := linkedplacex.place_id;
1495 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1497 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1498 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1499 IF address_street_word_ids IS NOT NULL THEN
1500 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1501 NEW.parent_place_id := linkedplacex.place_id;
1505 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1507 -- Is the WAY part of a relation
1508 IF NEW.parent_place_id IS NULL THEN
1509 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1511 -- At the moment we only process one type of relation - associatedStreet
1512 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1513 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1514 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1515 --RAISE WARNING 'node in way that is in a relation %',relation;
1516 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1517 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1523 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1529 -- Still nothing, just use the nearest road
1530 IF NEW.parent_place_id IS NULL THEN
1531 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1532 NEW.parent_place_id := location.place_id;
1535 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1538 -- If we didn't find any road fallback to standard method
1539 IF NEW.parent_place_id IS NOT NULL THEN
1541 -- Get the details of the parent road
1542 select * from search_name where place_id = NEW.parent_place_id INTO location;
1543 NEW.country_code := location.country_code;
1544 --DEBUG: RAISE WARNING 'Got parent details from search name';
1546 -- determine postcode
1547 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1548 NEW.postcode = NEW.address->'postcode';
1550 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1552 IF NEW.postcode is null THEN
1553 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1556 -- If there is no name it isn't searchable, don't bother to create a search record
1557 IF NEW.name is NULL THEN
1558 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1562 -- Merge address from parent
1563 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1564 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1566 -- Performance, it would be more acurate to do all the rest of the import
1567 -- process but it takes too long
1568 -- Just be happy with inheriting from parent road only
1570 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1571 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1572 --DEBUG: RAISE WARNING 'Place added to location table';
1575 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);
1576 --DEBUG: RAISE WARNING 'Place added to search table';
1583 -- ---------------------------------------------------------------------------
1585 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1587 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1589 -- see if we have any special relation members
1590 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1591 --DEBUG: RAISE WARNING 'Got relation members';
1593 IF relation_members IS NOT NULL THEN
1594 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1595 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1597 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1598 and osm_id = substring(relMember.member,2,10000)::bigint
1599 and class = 'place' order by rank_search desc limit 1 LOOP
1601 -- If we don't already have one use this as the centre point of the geometry
1602 IF NEW.centroid IS NULL THEN
1603 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1606 -- merge in the label name, re-init word vector
1607 IF NOT linkedPlacex.name IS NULL THEN
1608 NEW.name := linkedPlacex.name || NEW.name;
1609 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1612 -- merge in extra tags
1613 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1615 -- mark the linked place (excludes from search results)
1616 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1618 -- keep a note of the node id in case we need it for wikipedia in a bit
1619 linked_node_id := linkedPlacex.osm_id;
1620 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1621 --DEBUG: RAISE WARNING 'Linked label member';
1626 IF NEW.centroid IS NULL THEN
1628 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1629 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1631 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1632 and osm_id = substring(relMember.member,2,10000)::bigint
1633 and class = 'place' order by rank_search desc limit 1 LOOP
1635 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1636 -- But that can be fixed by explicitly setting the label in the data
1637 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1638 AND NEW.rank_address = linkedPlacex.rank_address THEN
1640 -- If we don't already have one use this as the centre point of the geometry
1641 IF NEW.centroid IS NULL THEN
1642 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1645 -- merge in the name, re-init word vector
1646 IF NOT linkedPlacex.name IS NULL THEN
1647 NEW.name := linkedPlacex.name || NEW.name;
1648 name_vector := make_keywords(NEW.name);
1651 -- merge in extra tags
1652 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1654 -- mark the linked place (excludes from search results)
1655 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1657 -- keep a note of the node id in case we need it for wikipedia in a bit
1658 linked_node_id := linkedPlacex.osm_id;
1659 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1660 --DEBUG: RAISE WARNING 'Linked admin_center';
1672 -- Name searches can be done for ways as well as relations
1673 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1675 -- not found one yet? how about doing a name search
1676 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1678 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1679 FOR linkedPlacex IN select placex.* from placex WHERE
1680 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1681 AND placex.rank_address = NEW.rank_address
1682 AND placex.place_id != NEW.place_id
1683 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1684 AND st_covers(NEW.geometry, placex.geometry)
1686 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1687 -- If we don't already have one use this as the centre point of the geometry
1688 IF NEW.centroid IS NULL THEN
1689 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1692 -- merge in the name, re-init word vector
1693 NEW.name := linkedPlacex.name || NEW.name;
1694 name_vector := make_keywords(NEW.name);
1696 -- merge in extra tags
1697 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1699 -- mark the linked place (excludes from search results)
1700 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1702 -- keep a note of the node id in case we need it for wikipedia in a bit
1703 linked_node_id := linkedPlacex.osm_id;
1704 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1705 --DEBUG: RAISE WARNING 'Linked named place';
1709 IF NEW.centroid IS NOT NULL THEN
1710 place_centroid := NEW.centroid;
1711 -- Place might have had only a name tag before but has now received translations
1712 -- from the linked place. Make sure a name tag for the default language exists in
1714 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1715 default_language := get_country_language_code(NEW.country_code);
1716 IF default_language IS NOT NULL THEN
1717 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1718 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1719 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1720 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1724 --DEBUG: RAISE WARNING 'Names updated from linked places';
1727 -- Use the maximum importance if a one could be computed from the linked object.
1728 IF linked_importance is not null AND
1729 (NEW.importance is null or NEW.importance < linked_importance) THEN
1730 NEW.importance = linked_importance;
1733 -- Still null? how about looking it up by the node id
1734 IF NEW.importance IS NULL THEN
1735 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1736 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;
1741 -- make sure all names are in the word table
1742 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1743 perform create_country(NEW.name, lower(NEW.country_code));
1744 --DEBUG: RAISE WARNING 'Country names updated';
1747 NEW.parent_place_id = 0;
1748 parent_place_id_rank = 0;
1751 -- convert isin to array of tokenids
1752 --DEBUG: RAISE WARNING 'Starting address search';
1753 isin_tokens := '{}'::int[];
1754 IF NEW.address IS NOT NULL THEN
1755 isin := avals(NEW.address);
1756 IF array_upper(isin, 1) IS NOT NULL THEN
1757 FOR i IN 1..array_upper(isin, 1) LOOP
1758 -- TODO further split terms with comma and semicolon
1759 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1760 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1761 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1762 isin_tokens := isin_tokens || address_street_word_id;
1765 -- merge word into address vector
1766 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1767 IF address_street_word_id IS NOT NULL THEN
1768 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1774 -- %NOTIGERDATA% IF 0 THEN
1775 -- for the USA we have an additional address table. Merge in zip codes from there too
1776 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1777 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1778 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1779 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1780 isin_tokens := isin_tokens || address_street_word_id;
1782 -- also merge in the single word version
1783 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1784 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1787 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1788 -- %NOTIGERDATA% END IF;
1790 -- RAISE WARNING 'ISIN: %', isin_tokens;
1792 -- Process area matches
1793 location_rank_search := 0;
1794 location_distance := 0;
1795 location_parent := NULL;
1796 -- added ourself as address already
1797 address_havelevel[NEW.rank_address] := true;
1798 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1800 SELECT * from getNearFeatures(NEW.partition,
1801 CASE WHEN NEW.rank_search >= 26
1802 AND NEW.rank_search < 30
1804 ELSE place_centroid END,
1805 search_maxrank, isin_tokens)
1807 IF location.rank_address != location_rank_search THEN
1808 location_rank_search := location.rank_address;
1809 IF location.isguess THEN
1810 location_distance := location.distance * 1.5;
1812 IF location.rank_address <= 12 THEN
1813 -- for county and above, if we have an area consider that exact
1814 -- (It would be nice to relax the constraint for places close to
1815 -- the boundary but we'd need the exact geometry for that. Too
1817 location_distance = 0;
1819 -- Below county level remain slightly fuzzy.
1820 location_distance := location.distance * 0.5;
1824 CONTINUE WHEN location.keywords <@ location_keywords;
1827 IF location.distance < location_distance OR NOT location.isguess THEN
1828 location_keywords := location.keywords;
1830 location_isaddress := NOT address_havelevel[location.rank_address];
1831 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1832 location_isaddress := ST_Contains(location_parent,location.centroid);
1835 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1836 -- Add it to the list of search terms
1837 IF location.rank_search > 4 THEN
1838 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1840 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1841 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1843 IF location_isaddress THEN
1844 -- add postcode if we have one
1845 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1846 IF location.postcode is not null THEN
1847 NEW.postcode = location.postcode;
1850 address_havelevel[location.rank_address] := true;
1851 IF NOT location.isguess THEN
1852 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1855 IF location.rank_address > parent_place_id_rank THEN
1856 NEW.parent_place_id = location.place_id;
1857 parent_place_id_rank = location.rank_address;
1862 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1867 --DEBUG: RAISE WARNING 'address computed';
1869 -- try using the isin value to find parent places
1870 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1871 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1872 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1873 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1875 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1877 --RAISE WARNING ' ISIN: %',location;
1879 IF location.rank_search > 4 THEN
1880 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1881 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1882 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1883 IF NEW.postcode is null AND location.postcode is not null
1884 AND NOT address_havelevel[location.rank_address] THEN
1885 NEW.postcode := location.postcode;
1888 address_havelevel[location.rank_address] := true;
1890 IF location.rank_address > parent_place_id_rank THEN
1891 NEW.parent_place_id = location.place_id;
1892 parent_place_id_rank = location.rank_address;
1901 --DEBUG: RAISE WARNING 'isin tokens processed';
1903 -- for long ways we should add search terms for the entire length
1904 IF st_length(NEW.geometry) > 0.05 THEN
1906 location_rank_search := 0;
1907 location_distance := 0;
1909 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1911 IF location.rank_address != location_rank_search THEN
1912 location_rank_search := location.rank_address;
1913 location_distance := location.distance * 1.5;
1916 IF location.rank_search > 4 AND location.distance < location_distance THEN
1918 -- Add it to the list of search terms
1919 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1920 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1921 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1928 --DEBUG: RAISE WARNING 'search terms for long ways added';
1930 IF NEW.address is not null AND NEW.address ? 'postcode'
1931 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1932 NEW.postcode := NEW.address->'postcode';
1935 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1936 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1939 -- if we have a name add this to the name search table
1940 IF NEW.name IS NOT NULL THEN
1942 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1943 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1944 --DEBUG: RAISE WARNING 'added to location (full)';
1947 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1948 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1949 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1952 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);
1953 --DEBUG: RAISE WARNING 'added to serach name (full)';
1957 -- If we've not managed to pick up a better one - default centroid
1958 IF NEW.centroid IS NULL THEN
1959 NEW.centroid := place_centroid;
1962 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1969 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1975 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1977 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1978 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1979 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1980 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1982 IF OLD.rank_address < 30 THEN
1984 -- mark everything linked to this place for re-indexing
1985 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1986 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1987 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1989 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1990 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1992 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1993 b := deleteRoad(OLD.partition, OLD.place_id);
1995 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1996 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1997 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1998 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1999 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
2003 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2005 IF OLD.rank_address < 26 THEN
2006 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2009 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2011 IF OLD.name is not null THEN
2012 b := deleteSearchName(OLD.partition, OLD.place_id);
2015 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2017 DELETE FROM place_addressline where place_id = OLD.place_id;
2019 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2021 -- remove from tables for special search
2022 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2023 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2025 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2028 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2036 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2042 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2044 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2045 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2046 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;
2048 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2054 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;
2056 -- interpolations are special
2057 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2058 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2067 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2072 existingplacex RECORD;
2073 existingline RECORD;
2074 existinggeometry GEOMETRY;
2075 existingplace_id BIGINT;
2080 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2081 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2082 -- filter wrong tupels
2083 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
2084 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2085 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2086 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2090 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2091 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2092 -- Have we already done this place?
2093 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;
2095 -- Get the existing place_id
2096 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2098 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2099 IF existing.osm_type IS NULL THEN
2100 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2103 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2104 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2106 -- 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)
2107 IF existingline.osm_id IS NOT NULL THEN
2108 delete from location_property_osmline where osm_id = NEW.osm_id;
2111 -- for interpolations invalidate all nodes on the line
2112 update placex p set indexed_status = 2
2113 from planet_osm_ways w
2114 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2117 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2118 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2121 IF existing.osm_type IS NULL THEN
2125 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2126 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2127 OR existing.geometry::text != NEW.geometry::text
2132 address = NEW.address,
2133 extratags = NEW.extratags,
2134 admin_level = NEW.admin_level,
2135 geometry = NEW.geometry
2136 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2141 ELSE -- insert to placex
2143 -- Patch in additional country names
2144 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2145 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2146 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2147 IF existing.name IS NOT NULL THEN
2148 NEW.name = existing.name || NEW.name;
2152 -- Have we already done this place?
2153 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;
2155 -- Get the existing place_id
2156 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;
2158 -- Handle a place changing type by removing the old data
2159 -- My generated 'place' types are causing havok because they overlap with real keys
2160 -- TODO: move them to their own special purpose key/class to avoid collisions
2161 IF existing.osm_type IS NULL THEN
2162 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2165 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2166 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2169 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2170 AND st_area(existing.geometry) > 0.02
2171 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2172 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2174 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2175 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2176 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2180 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2181 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2183 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2184 IF existingplacex.osm_type IS NULL OR
2185 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2188 IF existingplacex.osm_type IS NOT NULL THEN
2189 -- sanity check: ignore admin_level changes on places with too many active children
2190 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2191 --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;
2192 --LIMIT INDEXING: IF i > 100000 THEN
2193 --LIMIT INDEXING: RETURN null;
2194 --LIMIT INDEXING: END IF;
2197 IF existing.osm_type IS NOT NULL THEN
2198 -- pathological case caused by the triggerless copy into place during initial import
2199 -- force delete even for large areas, it will be reinserted later
2200 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;
2201 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2204 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2205 insert into placex (osm_type, osm_id, class, type, name,
2206 admin_level, address, extratags, geometry)
2207 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2208 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2210 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2215 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2216 IF existing.geometry::text != NEW.geometry::text
2217 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2218 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2221 -- Get the version of the geometry actually used (in placex table)
2222 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;
2224 -- Performance limit
2225 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2227 -- 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
2228 update placex set indexed_status = 2 where indexed_status = 0 and
2229 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2230 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2231 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2233 update placex set indexed_status = 2 where indexed_status = 0 and
2234 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2235 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2236 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2243 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2244 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2245 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2246 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2247 OR existing.geometry::text != NEW.geometry::text
2252 address = NEW.address,
2253 extratags = NEW.extratags,
2254 admin_level = NEW.admin_level,
2255 geometry = NEW.geometry
2256 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2259 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2260 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2261 -- postcode was deleted, no longer retain in placex
2262 DELETE FROM placex where place_id = existingplacex.place_id;
2266 NEW.name := hstore('ref', NEW.address->'postcode');
2269 IF NEW.class in ('boundary')
2270 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2271 DELETE FROM placex where place_id = existingplacex.place_id;
2277 address = NEW.address,
2278 parent_place_id = null,
2279 extratags = NEW.extratags,
2280 admin_level = NEW.admin_level,
2282 geometry = NEW.geometry
2283 where place_id = existingplacex.place_id;
2285 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2286 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2287 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2288 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2289 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);
2292 -- linked places should get potential new naming and addresses
2293 IF existingplacex.linked_place_id is not NULL THEN
2296 extratags = p.extratags,
2299 where x.place_id = existingplacex.linked_place_id
2300 and x.indexed_status = 0
2301 and x.osm_type = p.osm_type
2302 and x.osm_id = p.osm_id
2303 and x.class = p.class;
2308 -- Abort the add (we modified the existing place instead)
2313 $$ LANGUAGE plpgsql;
2316 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2321 IF name is null THEN
2325 FOR j IN 1..array_upper(languagepref,1) LOOP
2326 IF name ? languagepref[j] THEN
2327 result := trim(name->languagepref[j]);
2328 IF result != '' THEN
2334 -- anything will do as a fallback - just take the first name type thing there is
2335 RETURN trim((avals(name))[1]);
2338 LANGUAGE plpgsql IMMUTABLE;
2340 --housenumber only needed for tiger data
2341 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2353 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2354 currresult := trim(get_name_by_language(location.name, languagepref));
2355 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2356 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2357 prevresult := currresult;
2361 RETURN array_to_string(result,', ');
2366 DROP TYPE IF EXISTS addressline CASCADE;
2367 create type addressline as (
2374 admin_level INTEGER,
2377 rank_address INTEGER,
2381 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2384 for_place_id BIGINT;
2389 countrylocation RECORD;
2390 searchcountrycode varchar(2);
2391 searchhousenumber TEXT;
2392 searchhousename HSTORE;
2393 searchrankaddress INTEGER;
2394 searchpostcode TEXT;
2400 -- first query osmline (interpolation lines)
2401 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2402 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2403 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2404 IF for_place_id IS NOT NULL THEN
2405 searchhousenumber = in_housenumber::text;
2408 --then query tiger data
2409 -- %NOTIGERDATA% IF 0 THEN
2410 IF for_place_id IS NULL THEN
2411 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2412 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2413 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2414 IF for_place_id IS NOT NULL THEN
2415 searchhousenumber = in_housenumber::text;
2418 -- %NOTIGERDATA% END IF;
2420 -- %NOAUXDATA% IF 0 THEN
2421 IF for_place_id IS NULL THEN
2422 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2423 WHERE place_id = in_place_id
2424 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2426 -- %NOAUXDATA% END IF;
2429 IF for_place_id IS NULL THEN
2430 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2431 FROM location_postcode
2432 WHERE place_id = in_place_id
2433 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2436 IF for_place_id IS NULL THEN
2437 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2438 WHERE place_id = in_place_id and rank_search > 27
2439 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2442 IF for_place_id IS NULL THEN
2443 select coalesce(linked_place_id, place_id), country_code,
2444 housenumber, rank_search, postcode, null
2445 from placex where place_id = in_place_id
2446 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2449 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2452 hadcountry := false;
2454 select placex.place_id, osm_type, osm_id, name,
2455 class, type, admin_level, true as isaddress,
2456 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2457 0 as distance, country_code, postcode
2459 where place_id = for_place_id
2461 --RAISE WARNING '%',location;
2462 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2463 searchcountrycode := location.country_code;
2465 IF location.type in ('postcode', 'postal_code') THEN
2466 location.isaddress := FALSE;
2467 ELSEIF location.rank_address = 4 THEN
2470 IF location.rank_address < 4 AND NOT hadcountry THEN
2471 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2472 IF countryname IS NOT NULL THEN
2473 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2474 RETURN NEXT countrylocation;
2477 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2478 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2479 location.distance)::addressline;
2480 RETURN NEXT countrylocation;
2481 found := location.rank_address;
2485 select placex.place_id, osm_type, osm_id, name,
2486 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2487 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2488 admin_level, fromarea, isaddress,
2489 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,
2490 distance,country_code,postcode
2491 from place_addressline join placex on (address_place_id = placex.place_id)
2492 where place_addressline.place_id = for_place_id
2493 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2494 and address_place_id != for_place_id
2495 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2496 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2498 --RAISE WARNING '%',location;
2499 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2500 searchcountrycode := location.country_code;
2502 IF location.type in ('postcode', 'postal_code') THEN
2503 location.isaddress := FALSE;
2505 IF location.rank_address = 4 AND location.isaddress THEN
2508 IF location.rank_address < 4 AND NOT hadcountry THEN
2509 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2510 IF countryname IS NOT NULL THEN
2511 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2512 RETURN NEXT countrylocation;
2515 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2516 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2517 location.distance)::addressline;
2518 RETURN NEXT countrylocation;
2519 found := location.rank_address;
2523 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2524 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2525 IF countryname IS NOT NULL THEN
2526 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2527 RETURN NEXT location;
2531 IF searchcountrycode IS NOT NULL THEN
2532 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2533 RETURN NEXT location;
2536 IF searchhousename IS NOT NULL THEN
2537 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2538 RETURN NEXT location;
2541 IF searchhousenumber IS NOT NULL THEN
2542 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2543 RETURN NEXT location;
2546 IF searchpostcode IS NOT NULL THEN
2547 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2548 RETURN NEXT location;
2557 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2563 ELSEIF rank < 4 THEN
2565 ELSEIF rank < 8 THEN
2567 ELSEIF rank < 12 THEN
2569 ELSEIF rank < 16 THEN
2571 ELSEIF rank = 16 THEN
2573 ELSEIF rank = 17 THEN
2574 RETURN 'Town / Island';
2575 ELSEIF rank = 18 THEN
2576 RETURN 'Village / Hamlet';
2577 ELSEIF rank = 20 THEN
2579 ELSEIF rank = 21 THEN
2580 RETURN 'Postcode Area';
2581 ELSEIF rank = 22 THEN
2582 RETURN 'Croft / Farm / Locality / Islet';
2583 ELSEIF rank = 23 THEN
2584 RETURN 'Postcode Area';
2585 ELSEIF rank = 25 THEN
2586 RETURN 'Postcode Point';
2587 ELSEIF rank = 26 THEN
2588 RETURN 'Street / Major Landmark';
2589 ELSEIF rank = 27 THEN
2590 RETURN 'Minory Street / Path';
2591 ELSEIF rank = 28 THEN
2592 RETURN 'House / Building';
2594 RETURN 'Other: '||rank;
2601 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2607 ELSEIF rank < 2 THEN
2609 ELSEIF rank < 4 THEN
2611 ELSEIF rank = 5 THEN
2613 ELSEIF rank < 8 THEN
2615 ELSEIF rank < 12 THEN
2617 ELSEIF rank < 16 THEN
2619 ELSEIF rank = 16 THEN
2621 ELSEIF rank = 17 THEN
2622 RETURN 'Town / Village / Hamlet';
2623 ELSEIF rank = 20 THEN
2625 ELSEIF rank = 21 THEN
2626 RETURN 'Postcode Area';
2627 ELSEIF rank = 22 THEN
2628 RETURN 'Croft / Farm / Locality / Islet';
2629 ELSEIF rank = 23 THEN
2630 RETURN 'Postcode Area';
2631 ELSEIF rank = 25 THEN
2632 RETURN 'Postcode Point';
2633 ELSEIF rank = 26 THEN
2634 RETURN 'Street / Major Landmark';
2635 ELSEIF rank = 27 THEN
2636 RETURN 'Minory Street / Path';
2637 ELSEIF rank = 28 THEN
2638 RETURN 'House / Building';
2640 RETURN 'Other: '||rank;
2647 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2648 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2653 place_centroid GEOMETRY;
2654 out_partition INTEGER;
2655 out_parent_place_id BIGINT;
2657 address_street_word_id INTEGER;
2662 place_centroid := ST_Centroid(pointgeo);
2663 out_partition := get_partition(in_countrycode);
2664 out_parent_place_id := null;
2666 address_street_word_id := get_name_id(make_standard_name(in_street));
2667 IF address_street_word_id IS NOT NULL THEN
2668 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2669 out_parent_place_id := location.place_id;
2673 IF out_parent_place_id IS NULL THEN
2674 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2675 out_parent_place_id := location.place_id;
2679 out_postcode := in_postcode;
2680 IF out_postcode IS NULL THEN
2681 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2683 -- XXX look into postcode table
2686 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2687 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2688 newpoints := newpoints + 1;
2695 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2702 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2703 IF members[i+1] = member THEN
2704 result := result || members[i];
2713 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2719 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2720 IF members[i+1] = ANY(memberLabels) THEN
2721 RETURN NEXT members[i];
2730 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2731 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2733 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2734 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
2735 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2736 ), '') AS bytea), 'UTF8');
2738 LANGUAGE SQL IMMUTABLE STRICT;
2740 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2744 RETURN decode_url_part(p);
2746 WHEN others THEN return null;
2749 LANGUAGE plpgsql IMMUTABLE;
2751 DROP TYPE wikipedia_article_match CASCADE;
2752 create type wikipedia_article_match as (
2758 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2764 wiki_article_title TEXT;
2765 wiki_article_language TEXT;
2766 result wikipedia_article_match;
2768 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'];
2770 WHILE langs[i] IS NOT NULL LOOP
2771 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2772 IF wiki_article is not null THEN
2773 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2774 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2775 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2776 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2777 wiki_article := replace(wiki_article,' ','_');
2778 IF strpos(wiki_article, ':') IN (3,4) THEN
2779 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2780 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2782 wiki_article_title := trim(wiki_article);
2783 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;
2786 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2787 from wikipedia_article
2788 where language = wiki_article_language and
2789 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2791 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2792 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2793 where wikipedia_redirect.language = wiki_article_language and
2794 (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'\\',''))
2795 order by importance desc limit 1 INTO result;
2797 IF result.language is not null THEN
2808 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2809 RETURNS SETOF GEOMETRY
2823 remainingdepth INTEGER;
2828 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2830 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2831 RETURN NEXT geometry;
2835 remainingdepth := maxdepth - 1;
2836 area := ST_AREA(geometry);
2837 IF remainingdepth < 1 OR area < maxarea THEN
2838 RETURN NEXT geometry;
2842 xmin := st_xmin(geometry);
2843 xmax := st_xmax(geometry);
2844 ymin := st_ymin(geometry);
2845 ymax := st_ymax(geometry);
2846 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2848 -- if the geometry completely covers the box don't bother to slice any more
2849 IF ST_AREA(secbox) = area THEN
2850 RETURN NEXT geometry;
2854 xmid := (xmin+xmax)/2;
2855 ymid := (ymin+ymax)/2;
2858 FOR seg IN 1..4 LOOP
2861 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2864 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2867 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2870 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2873 IF st_intersects(geometry, secbox) THEN
2874 secgeo := st_intersection(geometry, secbox);
2875 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2876 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2877 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2879 RETURN NEXT geo.geom;
2891 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2892 RETURNS SETOF GEOMETRY
2897 -- 10000000000 is ~~ 1x1 degree
2898 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2899 RETURN NEXT geo.geom;
2907 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2911 osmtype character(1);
2915 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2916 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2917 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2918 -- force delete from place/placex by making it a very small geometry
2919 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;
2920 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2927 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2935 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2936 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2937 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2938 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2939 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2940 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2941 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'));
2942 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2943 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'));
2949 ELSEIF rank < 18 THEN
2951 ELSEIF rank < 20 THEN
2953 ELSEIF rank = 21 THEN
2955 ELSEIF rank < 24 THEN
2957 ELSEIF rank < 26 THEN
2958 diameter := 0.002; -- 100 to 200 meters
2959 ELSEIF rank < 28 THEN
2960 diameter := 0.001; -- 50 to 100 meters
2962 IF diameter > 0 THEN
2964 -- roads may cause reparenting for >27 rank places
2965 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2966 ELSEIF rank >= 16 THEN
2967 -- up to rank 16, street-less addresses may need reparenting
2968 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');
2970 -- for all other places the search terms may change as well
2971 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);