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_country(lookup_word TEXT, lookup_country_code varchar(2))
91 return_word_id INTEGER;
93 lookup_token := ' '||trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 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;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 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;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
145 nospace_lookup_token TEXT;
146 return_word_id INTEGER;
148 lookup_token := ' '||trim(lookup_word);
149 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
150 IF return_word_id IS NULL THEN
151 return_word_id := nextval('seq_word');
152 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
153 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
154 -- IF ' '||nospace_lookup_token != lookup_token THEN
155 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
168 RETURN getorcreate_name_id(lookup_word, '');
173 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
178 return_word_id INTEGER;
180 lookup_token := trim(lookup_word);
181 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
182 RETURN return_word_id;
185 LANGUAGE plpgsql IMMUTABLE;
187 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
192 return_word_id INTEGER;
194 lookup_token := ' '||trim(lookup_word);
195 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
196 RETURN return_word_id;
199 LANGUAGE plpgsql IMMUTABLE;
201 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
206 return_word_ids INTEGER[];
208 lookup_token := ' '||trim(lookup_word);
209 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
210 RETURN return_word_ids;
213 LANGUAGE plpgsql IMMUTABLE;
215 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
222 IF array_upper(a, 1) IS NULL THEN
225 IF array_upper(b, 1) IS NULL THEN
229 FOR i IN 1..array_upper(b, 1) LOOP
230 IF NOT (ARRAY[b[i]] <@ r) THEN
237 LANGUAGE plpgsql IMMUTABLE;
240 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
241 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
249 IF country_code = 'gb' THEN
250 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
253 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
256 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
261 ELSEIF country_code = 'sg' THEN
262 IF postcode ~ '^([0-9]{6})$' THEN
267 ELSEIF country_code = 'de' THEN
268 IF postcode ~ '^([0-9]{5})$' THEN
274 -- Guess at the postcode format and coverage (!)
275 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
279 -- Does it look splitable into and area and local code?
280 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
282 IF part IS NOT NULL THEN
285 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
294 LANGUAGE plpgsql IMMUTABLE;
296 -- Find the nearest artificial postcode for the given geometry.
297 -- TODO For areas there should not be more than two inside the geometry.
298 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
304 SELECT postcode FROM location_postcode
305 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
306 AND location_postcode.country_code = country
307 ORDER BY ST_Distance(geom, location_postcode.geometry)
310 RETURN item.postcode;
319 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
328 FOR item IN SELECT (each(src)).* LOOP
330 s := make_standard_name(item.value);
331 w := getorcreate_country(s, lookup_country_code);
333 words := regexp_split_to_array(item.value, E'[,;()]');
334 IF array_upper(words, 1) != 1 THEN
335 FOR j IN 1..array_upper(words, 1) LOOP
336 s := make_standard_name(words[j]);
338 w := getorcreate_country(s, lookup_country_code);
347 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
357 result := '{}'::INTEGER[];
359 FOR item IN SELECT (each(src)).* LOOP
361 s := make_standard_name(item.value);
363 w := getorcreate_name_id(s, item.value);
365 IF not(ARRAY[w] <@ result) THEN
366 result := result || w;
369 w := getorcreate_word_id(s);
371 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
372 result := result || w;
375 words := string_to_array(s, ' ');
376 IF array_upper(words, 1) IS NOT NULL THEN
377 FOR j IN 1..array_upper(words, 1) LOOP
378 IF (words[j] != '') THEN
379 w = getorcreate_word_id(words[j]);
380 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
381 result := result || w;
387 words := regexp_split_to_array(item.value, E'[,;()]');
388 IF array_upper(words, 1) != 1 THEN
389 FOR j IN 1..array_upper(words, 1) LOOP
390 s := make_standard_name(words[j]);
392 w := getorcreate_word_id(s);
393 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
394 result := result || w;
400 s := regexp_replace(item.value, '市$', '');
401 IF s != item.value THEN
402 s := make_standard_name(s);
404 w := getorcreate_name_id(s, item.value);
405 IF NOT (ARRAY[w] <@ result) THEN
406 result := result || w;
416 LANGUAGE plpgsql IMMUTABLE;
418 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
428 result := '{}'::INTEGER[];
430 s := make_standard_name(src);
431 w := getorcreate_name_id(s, src);
433 IF NOT (ARRAY[w] <@ result) THEN
434 result := result || w;
437 w := getorcreate_word_id(s);
439 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
440 result := result || w;
443 words := string_to_array(s, ' ');
444 IF array_upper(words, 1) IS NOT NULL THEN
445 FOR j IN 1..array_upper(words, 1) LOOP
446 IF (words[j] != '') THEN
447 w = getorcreate_word_id(words[j]);
448 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
449 result := result || w;
455 words := regexp_split_to_array(src, E'[,;()]');
456 IF array_upper(words, 1) != 1 THEN
457 FOR j IN 1..array_upper(words, 1) LOOP
458 s := make_standard_name(words[j]);
460 w := getorcreate_word_id(s);
461 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
462 result := result || w;
468 s := regexp_replace(src, '市$', '');
470 s := make_standard_name(s);
472 w := getorcreate_name_id(s, src);
473 IF NOT (ARRAY[w] <@ result) THEN
474 result := result || w;
482 LANGUAGE plpgsql IMMUTABLE;
484 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
487 place_centre GEOMETRY;
490 place_centre := ST_PointOnSurface(place);
492 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
494 -- Try for a OSM polygon
495 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
497 RETURN nearcountry.country_code;
500 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
502 -- Try for OSM fallback data
503 -- The order is to deal with places like HongKong that are 'states' within another polygon
504 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
506 RETURN nearcountry.country_code;
509 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
511 -- Natural earth data
512 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
514 RETURN nearcountry.country_code;
517 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
520 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
522 RETURN nearcountry.country_code;
525 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
527 -- Natural earth data
528 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
530 RETURN nearcountry.country_code;
536 LANGUAGE plpgsql IMMUTABLE;
538 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
543 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
545 RETURN lower(nearcountry.country_default_language_code);
550 LANGUAGE plpgsql IMMUTABLE;
552 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
557 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
559 RETURN lower(nearcountry.country_default_language_codes);
564 LANGUAGE plpgsql IMMUTABLE;
566 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
571 FOR nearcountry IN select partition from country_name where country_code = in_country_code
573 RETURN nearcountry.partition;
578 LANGUAGE plpgsql IMMUTABLE;
580 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
584 DELETE FROM location_area where place_id = OLD_place_id;
585 -- TODO:location_area
591 CREATE OR REPLACE FUNCTION add_location(
593 country_code varchar(2),
597 rank_address INTEGER,
613 IF rank_search > 25 THEN
614 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
617 x := deleteLocationArea(partition, place_id, rank_search);
619 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
620 IF in_postcode IS NULL OR in_postcode similar to '%(,|;)%' THEN
623 postcode := in_postcode;
626 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
627 centroid := ST_Centroid(geometry);
629 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
630 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
636 IF rank_address = 0 THEN
638 ELSEIF rank_search <= 14 THEN
640 ELSEIF rank_search <= 15 THEN
642 ELSEIF rank_search <= 16 THEN
644 ELSEIF rank_search <= 17 THEN
646 ELSEIF rank_search <= 21 THEN
648 ELSEIF rank_search = 25 THEN
652 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
654 secgeo := ST_Buffer(geometry, diameter);
655 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
665 -- find the parent road of the cut road parts
666 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
667 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
672 parent_place_id BIGINT;
673 address_street_word_ids INTEGER[];
679 addr_street = street;
682 IF addr_street is null and addr_place is null THEN
683 select nodes from planet_osm_ways where id = wayid INTO waynodes;
684 FOR location IN SELECT placex.address from placex
685 where osm_type = 'N' and osm_id = ANY(waynodes)
686 and placex.address is not null
687 and (placex.address ? 'street' or placex.address ? 'place')
688 and indexed_status < 100
690 addr_street = location.address->'street';
691 addr_place = location.address->'place';
695 IF addr_street IS NOT NULL THEN
696 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
697 IF address_street_word_ids IS NOT NULL THEN
698 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
699 parent_place_id := location.place_id;
704 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
705 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
706 IF address_street_word_ids IS NOT NULL THEN
707 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
708 parent_place_id := location.place_id;
713 IF parent_place_id is null THEN
714 FOR location IN SELECT place_id FROM placex
715 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
716 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
717 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
718 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
720 parent_place_id := location.place_id;
724 IF parent_place_id is null THEN
728 RETURN parent_place_id;
734 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
737 NEW.place_id := nextval('seq_place');
738 NEW.indexed_date := now();
740 IF NEW.indexed_status IS NULL THEN
741 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
742 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
743 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
747 NEW.indexed_status := 1; --STATUS_NEW
748 NEW.country_code := lower(get_country_code(NEW.linegeo));
750 NEW.partition := get_partition(NEW.country_code);
751 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
760 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
766 country_code VARCHAR(2);
767 default_language VARCHAR(10);
772 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
774 NEW.place_id := nextval('seq_place');
775 NEW.indexed_status := 1; --STATUS_NEW
777 NEW.country_code := lower(get_country_code(NEW.geometry));
779 NEW.partition := get_partition(NEW.country_code);
780 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
782 -- copy 'name' to or from the default language (if there is a default language)
783 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
784 default_language := get_country_language_code(NEW.country_code);
785 IF default_language IS NOT NULL THEN
786 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
787 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
788 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
789 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
794 IF NEW.osm_type = 'X' THEN
795 -- E'X'ternal records should already be in the right format so do nothing
797 NEW.rank_search := 30;
798 NEW.rank_address := NEW.rank_search;
800 -- By doing in postgres we have the country available to us - currently only used for postcode
801 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
803 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
804 -- most likely just a part of a multipolygon postcode boundary, throw it away
808 NEW.postcode := NEW.address->'postcode';
809 NEW.name := hstore('ref', NEW.postcode);
811 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
812 INTO NEW.rank_search, NEW.rank_address;
814 ELSEIF NEW.class = 'place' THEN
815 IF NEW.type in ('continent') THEN
816 NEW.rank_search := 2;
817 NEW.rank_address := NEW.rank_search;
818 NEW.country_code := NULL;
819 ELSEIF NEW.type in ('sea') THEN
820 NEW.rank_search := 2;
821 NEW.rank_address := 0;
822 NEW.country_code := NULL;
823 ELSEIF NEW.type in ('country') THEN
824 NEW.rank_search := 4;
825 NEW.rank_address := NEW.rank_search;
826 ELSEIF NEW.type in ('state') THEN
827 NEW.rank_search := 8;
828 NEW.rank_address := NEW.rank_search;
829 ELSEIF NEW.type in ('region') THEN
830 NEW.rank_search := 18; -- dropped from previous value of 10
831 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
832 ELSEIF NEW.type in ('county') THEN
833 NEW.rank_search := 12;
834 NEW.rank_address := NEW.rank_search;
835 ELSEIF NEW.type in ('city') THEN
836 NEW.rank_search := 16;
837 NEW.rank_address := NEW.rank_search;
838 ELSEIF NEW.type in ('island') THEN
839 NEW.rank_search := 17;
840 NEW.rank_address := 0;
841 ELSEIF NEW.type in ('town') THEN
842 NEW.rank_search := 18;
843 NEW.rank_address := 16;
844 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
845 NEW.rank_search := 19;
846 NEW.rank_address := 16;
847 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
848 NEW.rank_search := 20;
849 NEW.rank_address := NEW.rank_search;
850 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
851 NEW.rank_search := 20;
852 NEW.rank_address := 0;
853 -- Irish townlands, tagged as place=locality and locality=townland
854 IF (NEW.extratags -> 'locality') = 'townland' THEN
855 NEW.rank_address := 20;
857 ELSEIF NEW.type in ('neighbourhood') THEN
858 NEW.rank_search := 22;
859 NEW.rank_address := 22;
860 ELSEIF NEW.type in ('house','building') THEN
861 NEW.rank_search := 30;
862 NEW.rank_address := NEW.rank_search;
863 ELSEIF NEW.type in ('houses') THEN
864 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
865 NEW.rank_search := 28;
866 NEW.rank_address := 0;
869 ELSEIF NEW.class = 'boundary' THEN
870 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
871 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
874 NEW.rank_search := NEW.admin_level * 2;
875 IF NEW.type = 'administrative' THEN
876 NEW.rank_address := NEW.rank_search;
878 NEW.rank_address := 0;
880 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
881 NEW.rank_search := 22;
882 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
883 NEW.rank_address := NEW.rank_search;
885 NEW.rank_address := 0;
887 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
888 NEW.rank_search := 18;
889 NEW.rank_address := 0;
890 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
891 NEW.rank_search := 4;
892 NEW.rank_address := NEW.rank_search;
893 -- any feature more than 5 square miles is probably worth indexing
894 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
895 NEW.rank_search := 22;
896 NEW.rank_address := 0;
897 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
899 ELSEIF NEW.class = 'waterway' THEN
900 IF NEW.osm_type = 'R' THEN
901 NEW.rank_search := 16;
903 NEW.rank_search := 17;
905 NEW.rank_address := 0;
906 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
907 NEW.rank_search := 27;
908 NEW.rank_address := NEW.rank_search;
909 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
910 NEW.rank_search := 26;
911 NEW.rank_address := NEW.rank_search;
912 ELSEIF NEW.class = 'mountain_pass' THEN
913 NEW.rank_search := 20;
914 NEW.rank_address := 0;
919 IF NEW.rank_search > 30 THEN
920 NEW.rank_search := 30;
923 IF NEW.rank_address > 30 THEN
924 NEW.rank_address := 30;
927 IF (NEW.extratags -> 'capital') = 'yes' THEN
928 NEW.rank_search := NEW.rank_search - 1;
931 -- a country code make no sense below rank 4 (country)
932 IF NEW.rank_search < 4 THEN
933 NEW.country_code := NULL;
936 -- Block import below rank 22
937 -- IF NEW.rank_search > 22 THEN
941 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
943 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
945 IF NEW.rank_address > 0 THEN
946 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
947 -- Performance: We just can't handle re-indexing for country level changes
948 IF st_area(NEW.geometry) < 1 THEN
949 -- mark items within the geometry for re-indexing
950 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
952 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
953 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
954 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'));
955 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
956 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'));
959 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
961 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
962 IF NEW.type='postcode' THEN
964 ELSEIF NEW.rank_search < 16 THEN
966 ELSEIF NEW.rank_search < 18 THEN
968 ELSEIF NEW.rank_search < 20 THEN
970 ELSEIF NEW.rank_search = 21 THEN
972 ELSEIF NEW.rank_search < 24 THEN
974 ELSEIF NEW.rank_search < 26 THEN
975 diameter := 0.002; -- 100 to 200 meters
976 ELSEIF NEW.rank_search < 28 THEN
977 diameter := 0.001; -- 50 to 100 meters
980 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
981 IF NEW.rank_search >= 26 THEN
982 -- roads may cause reparenting for >27 rank places
983 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
984 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
985 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
986 ELSEIF NEW.rank_search >= 16 THEN
987 -- up to rank 16, street-less addresses may need reparenting
988 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');
990 -- for all other places the search terms may change as well
991 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);
998 -- add to tables for special search
999 -- Note: won't work on initial import because the classtype tables
1000 -- do not yet exist. It won't hurt either.
1001 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1002 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1004 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1005 USING NEW.place_id, ST_Centroid(NEW.geometry);
1014 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1018 place_centroid GEOMETRY;
1022 startnumber INTEGER;
1027 sectiongeo GEOMETRY;
1032 IF OLD.indexed_status = 100 THEN
1033 delete from location_property_osmline where place_id = OLD.place_id;
1037 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1041 NEW.interpolationtype = NEW.address->'interpolation';
1043 place_centroid := ST_PointOnSurface(NEW.linegeo);
1044 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1045 NEW.address->'place',
1046 NEW.partition, place_centroid, NEW.linegeo);
1049 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1050 NEW.postcode = NEW.address->'postcode';
1053 -- if the line was newly inserted, split the line as necessary
1054 IF OLD.indexed_status = 1 THEN
1055 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1057 IF array_upper(waynodes, 1) IS NULL THEN
1061 linegeo := NEW.linegeo;
1062 startnumber := NULL;
1063 postcode := NEW.postcode;
1065 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1067 select osm_id, address, geometry
1068 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1069 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1070 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1071 IF nextnode.osm_id IS NOT NULL THEN
1072 --RAISE NOTICE 'place_id is not null';
1073 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1074 -- Make sure that the point is actually on the line. That might
1075 -- be a bit paranoid but ensures that the algorithm still works
1076 -- should osm2pgsql attempt to repair geometries.
1077 splitline := split_line_on_node(linegeo, nextnode.geometry);
1078 sectiongeo := ST_GeometryN(splitline, 1);
1079 linegeo := ST_GeometryN(splitline, 2);
1081 sectiongeo = linegeo;
1083 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1085 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1086 AND startnumber != endnumber
1087 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1089 IF (startnumber > endnumber) THEN
1090 housenum := endnumber;
1091 endnumber := startnumber;
1092 startnumber := housenum;
1093 sectiongeo := ST_Reverse(sectiongeo);
1096 seg_postcode := coalesce(postcode,
1097 prevnode.address->'postcode',
1098 nextnode.address->'postcode');
1100 IF NEW.startnumber IS NULL THEN
1101 NEW.startnumber := startnumber;
1102 NEW.endnumber := endnumber;
1103 NEW.linegeo := sectiongeo;
1104 NEW.postcode := seg_postcode;
1106 insert into location_property_osmline
1107 (linegeo, partition, osm_id, parent_place_id,
1108 startnumber, endnumber, interpolationtype,
1109 address, postcode, country_code,
1110 geometry_sector, indexed_status)
1111 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1112 startnumber, endnumber, NEW.interpolationtype,
1113 NEW.address, seg_postcode,
1114 NEW.country_code, NEW.geometry_sector, 0);
1118 -- early break if we are out of line string,
1119 -- might happen when a line string loops back on itself
1120 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1124 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1125 prevnode := nextnode;
1130 -- marking descendants for reparenting is not needed, because there are
1131 -- actually no descendants for interpolation lines
1137 -- Trigger for updates of location_postcode
1139 -- Computes the parent object the postcode most likely refers to.
1140 -- This will be the place that determines the address displayed when
1141 -- searching for this postcode.
1142 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1149 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1153 NEW.indexed_date = now();
1155 partition := get_partition(NEW.country_code);
1157 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1158 INTO NEW.rank_search, NEW.rank_address;
1160 NEW.parent_place_id = 0;
1163 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1164 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1166 NEW.parent_place_id = location.place_id;
1174 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1179 place_centroid GEOMETRY;
1181 search_maxdistance FLOAT[];
1182 search_mindistance FLOAT[];
1183 address_havelevel BOOLEAN[];
1190 relation_members TEXT[];
1192 linkedplacex RECORD;
1193 search_diameter FLOAT;
1194 search_prevdiameter FLOAT;
1195 search_maxrank INTEGER;
1196 address_maxrank INTEGER;
1197 address_street_word_id INTEGER;
1198 address_street_word_ids INTEGER[];
1199 parent_place_id_rank BIGINT;
1207 location_rank_search INTEGER;
1208 location_distance FLOAT;
1209 location_parent GEOMETRY;
1210 location_isaddress BOOLEAN;
1211 location_keywords INTEGER[];
1213 default_language TEXT;
1214 name_vector INTEGER[];
1215 nameaddress_vector INTEGER[];
1217 linked_node_id BIGINT;
1218 linked_importance FLOAT;
1219 linked_wikipedia TEXT;
1224 IF OLD.indexed_status = 100 THEN
1225 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1226 delete from placex where place_id = OLD.place_id;
1230 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1234 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1236 NEW.indexed_date = now();
1238 result := deleteSearchName(NEW.partition, NEW.place_id);
1239 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1240 result := deleteRoad(NEW.partition, NEW.place_id);
1241 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1242 UPDATE placex set linked_place_id = null, indexed_status = 2
1243 where linked_place_id = NEW.place_id;
1244 -- update not necessary for osmline, cause linked_place_id does not exist
1246 IF NEW.linked_place_id is not null THEN
1247 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1251 --DEBUG: RAISE WARNING 'Copy over address tags';
1252 IF NEW.address is not NULL THEN
1253 IF NEW.address ? 'conscriptionnumber' THEN
1254 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1255 IF NEW.address ? 'streetnumber' THEN
1256 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1257 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1259 NEW.housenumber := NEW.address->'conscriptionnumber';
1261 ELSEIF NEW.address ? 'streetnumber' THEN
1262 NEW.housenumber := NEW.address->'streetnumber';
1263 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1264 ELSEIF NEW.address ? 'housenumber' THEN
1265 NEW.housenumber := NEW.address->'housenumber';
1266 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1269 addr_street = NEW.address->'street';
1270 addr_place = NEW.address->'place';
1273 -- Speed up searches - just use the centroid of the feature
1274 -- cheaper but less acurate
1275 place_centroid := ST_PointOnSurface(NEW.geometry);
1276 NEW.centroid := null;
1277 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1279 -- recalculate country and partition
1280 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1281 -- for countries, believe the mapped country code,
1282 -- so that we remain in the right partition if the boundaries
1284 NEW.country_code := lower(NEW.address->'country');
1285 NEW.partition := get_partition(lower(NEW.country_code));
1286 IF NEW.partition = 0 THEN
1287 NEW.country_code := lower(get_country_code(place_centroid));
1288 NEW.partition := get_partition(NEW.country_code);
1291 IF NEW.rank_search >= 4 THEN
1292 NEW.country_code := lower(get_country_code(place_centroid));
1294 NEW.country_code := NULL;
1296 NEW.partition := get_partition(NEW.country_code);
1298 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1300 -- waterway ways are linked when they are part of a relation and have the same class/type
1301 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1302 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1304 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1305 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1306 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1307 FOR linked_node_id IN SELECT place_id FROM placex
1308 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1309 and class = NEW.class and type = NEW.type
1310 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1312 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1317 --DEBUG: RAISE WARNING 'Waterway processed';
1320 -- Adding ourselves to the list simplifies address calculations later
1321 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1322 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1324 -- What level are we searching from
1325 search_maxrank := NEW.rank_search;
1327 -- Thought this wasn't needed but when we add new languages to the country_name table
1328 -- we need to update the existing names
1329 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1330 default_language := get_country_language_code(NEW.country_code);
1331 IF default_language IS NOT NULL THEN
1332 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1333 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1334 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1335 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1339 --DEBUG: RAISE WARNING 'Local names updated';
1341 -- Initialise the name vector using our name
1342 name_vector := make_keywords(NEW.name);
1343 nameaddress_vector := '{}'::int[];
1346 address_havelevel[i] := false;
1349 NEW.importance := null;
1350 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1351 IF NEW.importance IS NULL THEN
1352 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;
1355 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1357 -- ---------------------------------------------------------------------------
1358 -- For low level elements we inherit from our parent road
1359 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1361 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1363 -- We won't get a better centroid, besides these places are too small to care
1364 NEW.centroid := place_centroid;
1366 NEW.parent_place_id := null;
1368 -- if we have a POI and there is no address information,
1369 -- see if we can get it from a surrounding building
1370 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1371 AND NEW.housenumber IS NULL THEN
1372 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1373 and address is not null
1374 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1375 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1378 NEW.housenumber := location.address->'housenumber';
1379 addr_street := location.address->'street';
1380 addr_place := location.address->'place';
1381 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1385 -- We have to find our parent road.
1386 -- Copy data from linked items (points on ways, addr:street links, relations)
1388 -- Is this object part of a relation?
1389 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1391 -- At the moment we only process one type of relation - associatedStreet
1392 IF relation.tags @> ARRAY['associatedStreet'] THEN
1393 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1394 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1395 --RAISE WARNING 'node in relation %',relation;
1396 SELECT place_id from placex where osm_type = 'W'
1397 and osm_id = substring(relation.members[i],2,200)::bigint
1398 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1403 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1405 -- Note that addr:street links can only be indexed once the street itself is indexed
1406 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1407 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1408 IF address_street_word_ids IS NOT NULL THEN
1409 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1410 NEW.parent_place_id := location.place_id;
1414 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1416 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1417 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1418 IF address_street_word_ids IS NOT NULL THEN
1419 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1420 NEW.parent_place_id := location.place_id;
1424 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1426 -- Is this node part of an interpolation?
1427 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1429 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1430 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1433 NEW.parent_place_id := location.parent_place_id;
1436 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1438 -- Is this node part of a way?
1439 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1441 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
1442 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)
1444 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1446 -- Way IS a road then we are on it - that must be our road
1447 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1448 --RAISE WARNING 'node in way that is a street %',location;
1449 NEW.parent_place_id := location.place_id;
1451 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1453 -- If the way mentions a street or place address, try that for parenting.
1454 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1455 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1456 IF address_street_word_ids IS NOT NULL THEN
1457 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1458 NEW.parent_place_id := linkedplacex.place_id;
1462 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1464 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1465 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1466 IF address_street_word_ids IS NOT NULL THEN
1467 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1468 NEW.parent_place_id := linkedplacex.place_id;
1472 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1474 -- Is the WAY part of a relation
1475 IF NEW.parent_place_id IS NULL THEN
1476 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1478 -- At the moment we only process one type of relation - associatedStreet
1479 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1480 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1481 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1482 --RAISE WARNING 'node in way that is in a relation %',relation;
1483 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1484 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1490 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1496 -- Still nothing, just use the nearest road
1497 IF NEW.parent_place_id IS NULL THEN
1498 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1499 NEW.parent_place_id := location.place_id;
1502 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1505 -- If we didn't find any road fallback to standard method
1506 IF NEW.parent_place_id IS NOT NULL THEN
1508 -- Get the details of the parent road
1509 select * from search_name where place_id = NEW.parent_place_id INTO location;
1510 NEW.country_code := location.country_code;
1511 --DEBUG: RAISE WARNING 'Got parent details from search name';
1513 -- determine postcode
1514 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1515 NEW.postcode = NEW.address->'postcode';
1517 SELECT postcode FROM placex WHERE place_id = parent_place_id INTO NEW.postcode;
1519 IF NEW.postcode is null THEN
1520 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1523 -- Merge the postcode into the parent's address if necessary
1524 IF NEW.postcode IS NOT NULL THEN
1525 --DEBUG: RAISE WARNING 'Merging postcode into parent';
1526 isin_tokens := '{}'::int[];
1527 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1528 IF address_street_word_id is not null
1529 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1530 isin_tokens := isin_tokens || address_street_word_id;
1532 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1533 IF address_street_word_id is not null
1534 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1535 isin_tokens := isin_tokens || address_street_word_id;
1537 IF isin_tokens != '{}'::int[] THEN
1539 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1540 WHERE place_id = NEW.parent_place_id;
1544 -- If there is no name it isn't searchable, don't bother to create a search record
1545 IF NEW.name is NULL THEN
1546 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1550 -- Merge address from parent
1551 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1552 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1554 -- Performance, it would be more acurate to do all the rest of the import
1555 -- process but it takes too long
1556 -- Just be happy with inheriting from parent road only
1558 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1559 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1560 --DEBUG: RAISE WARNING 'Place added to location table';
1563 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);
1564 --DEBUG: RAISE WARNING 'Place added to search table';
1571 -- ---------------------------------------------------------------------------
1573 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1575 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1577 -- see if we have any special relation members
1578 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1579 --DEBUG: RAISE WARNING 'Got relation members';
1581 IF relation_members IS NOT NULL THEN
1582 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1583 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1585 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1586 and osm_id = substring(relMember.member,2,10000)::bigint
1587 and class = 'place' order by rank_search desc limit 1 LOOP
1589 -- If we don't already have one use this as the centre point of the geometry
1590 IF NEW.centroid IS NULL THEN
1591 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1594 -- merge in the label name, re-init word vector
1595 IF NOT linkedPlacex.name IS NULL THEN
1596 NEW.name := linkedPlacex.name || NEW.name;
1597 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1600 -- merge in extra tags
1601 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1603 -- mark the linked place (excludes from search results)
1604 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1606 -- keep a note of the node id in case we need it for wikipedia in a bit
1607 linked_node_id := linkedPlacex.osm_id;
1608 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1609 --DEBUG: RAISE WARNING 'Linked label member';
1614 IF NEW.centroid IS NULL THEN
1616 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1617 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1619 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1620 and osm_id = substring(relMember.member,2,10000)::bigint
1621 and class = 'place' order by rank_search desc limit 1 LOOP
1623 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1624 -- But that can be fixed by explicitly setting the label in the data
1625 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1626 AND NEW.rank_address = linkedPlacex.rank_address THEN
1628 -- If we don't already have one use this as the centre point of the geometry
1629 IF NEW.centroid IS NULL THEN
1630 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1633 -- merge in the name, re-init word vector
1634 IF NOT linkedPlacex.name IS NULL THEN
1635 NEW.name := linkedPlacex.name || NEW.name;
1636 name_vector := make_keywords(NEW.name);
1639 -- merge in extra tags
1640 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1642 -- mark the linked place (excludes from search results)
1643 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1645 -- keep a note of the node id in case we need it for wikipedia in a bit
1646 linked_node_id := linkedPlacex.osm_id;
1647 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1648 --DEBUG: RAISE WARNING 'Linked admin_center';
1660 -- Name searches can be done for ways as well as relations
1661 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1663 -- not found one yet? how about doing a name search
1664 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1666 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1667 FOR linkedPlacex IN select placex.* from placex WHERE
1668 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1669 AND placex.rank_address = NEW.rank_address
1670 AND placex.place_id != NEW.place_id
1671 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1672 AND st_covers(NEW.geometry, placex.geometry)
1674 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1675 -- If we don't already have one use this as the centre point of the geometry
1676 IF NEW.centroid IS NULL THEN
1677 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1680 -- merge in the name, re-init word vector
1681 NEW.name := linkedPlacex.name || NEW.name;
1682 name_vector := make_keywords(NEW.name);
1684 -- merge in extra tags
1685 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1687 -- mark the linked place (excludes from search results)
1688 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1690 -- keep a note of the node id in case we need it for wikipedia in a bit
1691 linked_node_id := linkedPlacex.osm_id;
1692 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1693 --DEBUG: RAISE WARNING 'Linked named place';
1697 IF NEW.centroid IS NOT NULL THEN
1698 place_centroid := NEW.centroid;
1699 -- Place might have had only a name tag before but has now received translations
1700 -- from the linked place. Make sure a name tag for the default language exists in
1702 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1703 default_language := get_country_language_code(NEW.country_code);
1704 IF default_language IS NOT NULL THEN
1705 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1706 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1707 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1708 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1712 --DEBUG: RAISE WARNING 'Names updated from linked places';
1715 -- Use the maximum importance if a one could be computed from the linked object.
1716 IF linked_importance is not null AND
1717 (NEW.importance is null or NEW.importance < linked_importance) THEN
1718 NEW.importance = linked_importance;
1721 -- Still null? how about looking it up by the node id
1722 IF NEW.importance IS NULL THEN
1723 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1724 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;
1729 -- make sure all names are in the word table
1730 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1731 perform create_country(NEW.name, lower(NEW.country_code));
1732 --DEBUG: RAISE WARNING 'Country names updated';
1735 NEW.parent_place_id = 0;
1736 parent_place_id_rank = 0;
1739 -- convert isin to array of tokenids
1740 --DEBUG: RAISE WARNING 'Starting address search';
1741 isin_tokens := '{}'::int[];
1742 IF NEW.address IS NOT NULL THEN
1743 isin := avals(NEW.address);
1744 IF array_upper(isin, 1) IS NOT NULL THEN
1745 FOR i IN 1..array_upper(isin, 1) LOOP
1746 -- TODO further split terms with comma and semicolon
1747 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1748 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1749 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1750 isin_tokens := isin_tokens || address_street_word_id;
1753 -- merge word into address vector
1754 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1755 IF address_street_word_id IS NOT NULL THEN
1756 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1762 -- %NOTIGERDATA% IF 0 THEN
1763 -- for the USA we have an additional address table. Merge in zip codes from there too
1764 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1765 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1766 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1767 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1768 isin_tokens := isin_tokens || address_street_word_id;
1770 -- also merge in the single word version
1771 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1772 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1775 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1776 -- %NOTIGERDATA% END IF;
1778 -- RAISE WARNING 'ISIN: %', isin_tokens;
1780 -- Process area matches
1781 location_rank_search := 0;
1782 location_distance := 0;
1783 location_parent := NULL;
1784 -- added ourself as address already
1785 address_havelevel[NEW.rank_address] := true;
1786 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1788 SELECT * from getNearFeatures(NEW.partition,
1789 CASE WHEN NEW.rank_search >= 26
1790 AND NEW.rank_search < 30
1792 ELSE place_centroid END,
1793 search_maxrank, isin_tokens)
1795 IF location.rank_address != location_rank_search THEN
1796 location_rank_search := location.rank_address;
1797 IF location.isguess THEN
1798 location_distance := location.distance * 1.5;
1800 IF location.rank_address <= 12 THEN
1801 -- for county and above, if we have an area consider that exact
1802 -- (It would be nice to relax the constraint for places close to
1803 -- the boundary but we'd need the exact geometry for that. Too
1805 location_distance = 0;
1807 -- Below county level remain slightly fuzzy.
1808 location_distance := location.distance * 0.5;
1812 CONTINUE WHEN location.keywords <@ location_keywords;
1815 IF location.distance < location_distance OR NOT location.isguess THEN
1816 location_keywords := location.keywords;
1818 location_isaddress := NOT address_havelevel[location.rank_address];
1819 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1820 location_isaddress := ST_Contains(location_parent,location.centroid);
1823 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1824 -- Add it to the list of search terms
1825 IF location.rank_search > 4 THEN
1826 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1828 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1829 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1831 IF location_isaddress THEN
1832 -- add postcode if we have one
1833 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1834 IF location.postcode is not null THEN
1835 NEW.postcode = location.postcode;
1838 address_havelevel[location.rank_address] := true;
1839 IF NOT location.isguess THEN
1840 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1843 IF location.rank_address > parent_place_id_rank THEN
1844 NEW.parent_place_id = location.place_id;
1845 parent_place_id_rank = location.rank_address;
1850 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1855 --DEBUG: RAISE WARNING 'address computed';
1857 -- try using the isin value to find parent places
1858 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1859 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1860 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1861 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1863 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1865 --RAISE WARNING ' ISIN: %',location;
1867 IF location.rank_search > 4 THEN
1868 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1869 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1870 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1871 IF NEW.postcode is null AND location.postcode is not null
1872 AND NOT address_havelevel[location.rank_address] THEN
1873 NEW.postcode := location.postcode;
1876 address_havelevel[location.rank_address] := true;
1878 IF location.rank_address > parent_place_id_rank THEN
1879 NEW.parent_place_id = location.place_id;
1880 parent_place_id_rank = location.rank_address;
1889 --DEBUG: RAISE WARNING 'isin tokens processed';
1891 -- for long ways we should add search terms for the entire length
1892 IF st_length(NEW.geometry) > 0.05 THEN
1894 location_rank_search := 0;
1895 location_distance := 0;
1897 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1899 IF location.rank_address != location_rank_search THEN
1900 location_rank_search := location.rank_address;
1901 location_distance := location.distance * 1.5;
1904 IF location.rank_search > 4 AND location.distance < location_distance THEN
1906 -- Add it to the list of search terms
1907 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1908 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1909 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1916 --DEBUG: RAISE WARNING 'search terms for long ways added';
1918 IF NEW.address is not null AND NEW.address ? 'postcode'
1919 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1920 NEW.postcode := NEW.address->'postcode';
1923 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1924 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1927 -- if we have a name add this to the name search table
1928 IF NEW.name IS NOT NULL THEN
1930 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1931 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1932 --DEBUG: RAISE WARNING 'added to location (full)';
1935 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1936 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1937 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1940 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);
1941 --DEBUG: RAISE WARNING 'added to serach name (full)';
1945 -- If we've not managed to pick up a better one - default centroid
1946 IF NEW.centroid IS NULL THEN
1947 NEW.centroid := place_centroid;
1950 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1957 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1963 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1965 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1966 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1967 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1968 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1970 IF OLD.rank_address < 30 THEN
1972 -- mark everything linked to this place for re-indexing
1973 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1974 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1975 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1977 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1978 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1980 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1981 b := deleteRoad(OLD.partition, OLD.place_id);
1983 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1984 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1985 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1986 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1987 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1991 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1993 IF OLD.rank_address < 26 THEN
1994 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1997 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1999 IF OLD.name is not null THEN
2000 b := deleteSearchName(OLD.partition, OLD.place_id);
2003 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2005 DELETE FROM place_addressline where place_id = OLD.place_id;
2007 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2009 -- remove from tables for special search
2010 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2011 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2013 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2016 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2024 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2030 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2032 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2033 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2034 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;
2036 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2042 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;
2044 -- interpolations are special
2045 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2046 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2055 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2060 existingplacex RECORD;
2061 existingline RECORD;
2062 existinggeometry GEOMETRY;
2063 existingplace_id BIGINT;
2068 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2069 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2070 -- filter wrong tupels
2071 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
2072 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2073 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2074 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2078 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2079 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2080 -- Have we already done this place?
2081 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;
2083 -- Get the existing place_id
2084 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2086 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2087 IF existing.osm_type IS NULL THEN
2088 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2091 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2092 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2094 -- 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)
2095 IF existingline.osm_id IS NOT NULL THEN
2096 delete from location_property_osmline where osm_id = NEW.osm_id;
2099 -- for interpolations invalidate all nodes on the line
2100 update placex p set indexed_status = 2
2101 from planet_osm_ways w
2102 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2105 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2106 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2109 IF existing.osm_type IS NULL THEN
2113 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2114 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2115 OR existing.geometry::text != NEW.geometry::text
2120 address = NEW.address,
2121 extratags = NEW.extratags,
2122 admin_level = NEW.admin_level,
2123 geometry = NEW.geometry
2124 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2129 ELSE -- insert to placex
2131 -- Patch in additional country names
2132 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2133 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2134 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2135 IF existing.name IS NOT NULL THEN
2136 NEW.name = existing.name || NEW.name;
2140 -- Have we already done this place?
2141 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;
2143 -- Get the existing place_id
2144 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;
2146 -- Handle a place changing type by removing the old data
2147 -- My generated 'place' types are causing havok because they overlap with real keys
2148 -- TODO: move them to their own special purpose key/class to avoid collisions
2149 IF existing.osm_type IS NULL THEN
2150 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2153 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2154 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2157 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2158 AND st_area(existing.geometry) > 0.02
2159 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2160 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2162 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2163 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2164 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2168 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2169 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2171 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2172 IF existingplacex.osm_type IS NULL OR
2173 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2176 IF existingplacex.osm_type IS NOT NULL THEN
2177 -- sanity check: ignore admin_level changes on places with too many active children
2178 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2179 --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;
2180 --LIMIT INDEXING: IF i > 100000 THEN
2181 --LIMIT INDEXING: RETURN null;
2182 --LIMIT INDEXING: END IF;
2185 IF existing.osm_type IS NOT NULL THEN
2186 -- pathological case caused by the triggerless copy into place during initial import
2187 -- force delete even for large areas, it will be reinserted later
2188 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;
2189 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2192 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2193 insert into placex (osm_type, osm_id, class, type, name,
2194 admin_level, address, extratags, geometry)
2195 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2196 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2198 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2203 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2204 IF existing.geometry::text != NEW.geometry::text
2205 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2206 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2209 -- Get the version of the geometry actually used (in placex table)
2210 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;
2212 -- Performance limit
2213 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2215 -- 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
2216 update placex set indexed_status = 2 where indexed_status = 0 and
2217 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2218 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2219 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2221 update placex set indexed_status = 2 where indexed_status = 0 and
2222 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2223 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2224 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2231 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2232 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2233 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2234 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2235 OR existing.geometry::text != NEW.geometry::text
2240 address = NEW.address,
2241 extratags = NEW.extratags,
2242 admin_level = NEW.admin_level,
2243 geometry = NEW.geometry
2244 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2247 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2248 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2249 -- postcode was deleted, no longer retain in placex
2250 DELETE FROM placex where place_id = existingplacex.place_id;
2254 NEW.name := hstore('ref', NEW.address->'postcode');
2257 IF NEW.class in ('boundary')
2258 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2259 DELETE FROM placex where place_id = existingplacex.place_id;
2265 address = NEW.address,
2266 parent_place_id = null,
2267 extratags = NEW.extratags,
2268 admin_level = NEW.admin_level,
2270 geometry = NEW.geometry
2271 where place_id = existingplacex.place_id;
2273 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2274 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2275 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2276 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2277 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);
2280 -- linked places should get potential new naming and addresses
2281 IF existingplacex.linked_place_id is not NULL THEN
2284 extratags = p.extratags,
2287 where x.place_id = existingplacex.linked_place_id
2288 and x.indexed_status = 0
2289 and x.osm_type = p.osm_type
2290 and x.osm_id = p.osm_id
2291 and x.class = p.class;
2296 -- Abort the add (we modified the existing place instead)
2301 $$ LANGUAGE plpgsql;
2304 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2309 IF name is null THEN
2313 FOR j IN 1..array_upper(languagepref,1) LOOP
2314 IF name ? languagepref[j] THEN
2315 result := trim(name->languagepref[j]);
2316 IF result != '' THEN
2322 -- anything will do as a fallback - just take the first name type thing there is
2323 RETURN trim((avals(name))[1]);
2326 LANGUAGE plpgsql IMMUTABLE;
2329 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2340 search := ARRAY['ref'];
2343 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2346 select rank_address,name,distance,length(name::text) as namelength
2347 from place_addressline join placex on (address_place_id = placex.place_id)
2348 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2349 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2351 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2352 FOR j IN 1..array_upper(search, 1) LOOP
2353 FOR k IN 1..array_upper(location.name, 1) LOOP
2354 IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
2355 result[(100 - location.rank_address)] := trim(location.name[k].value);
2356 found := location.rank_address;
2363 RETURN array_to_string(result,', ');
2368 --housenumber only needed for tiger data
2369 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2381 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2382 currresult := trim(get_name_by_language(location.name, languagepref));
2383 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2384 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2385 prevresult := currresult;
2389 RETURN array_to_string(result,', ');
2394 DROP TYPE IF EXISTS addressline CASCADE;
2395 create type addressline as (
2402 admin_level INTEGER,
2405 rank_address INTEGER,
2409 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2412 for_place_id BIGINT;
2417 countrylocation RECORD;
2418 searchcountrycode varchar(2);
2419 searchhousenumber TEXT;
2420 searchhousename HSTORE;
2421 searchrankaddress INTEGER;
2422 searchpostcode TEXT;
2428 -- first query osmline (interpolation lines)
2429 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2430 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2431 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2432 IF for_place_id IS NOT NULL THEN
2433 searchhousenumber = in_housenumber::text;
2436 --then query tiger data
2437 -- %NOTIGERDATA% IF 0 THEN
2438 IF for_place_id IS NULL THEN
2439 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2440 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2441 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2442 IF for_place_id IS NOT NULL THEN
2443 searchhousenumber = in_housenumber::text;
2446 -- %NOTIGERDATA% END IF;
2448 -- %NOAUXDATA% IF 0 THEN
2449 IF for_place_id IS NULL THEN
2450 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2451 WHERE place_id = in_place_id
2452 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2454 -- %NOAUXDATA% END IF;
2456 IF for_place_id IS NULL THEN
2457 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2458 WHERE place_id = in_place_id and rank_search > 27
2459 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2462 IF for_place_id IS NULL THEN
2463 select coalesce(linked_place_id, place_id), country_code,
2464 housenumber, rank_search, postcode, null
2465 from placex where place_id = in_place_id
2466 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2469 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2472 hadcountry := false;
2474 select placex.place_id, osm_type, osm_id,
2475 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2476 class, type, admin_level, true as fromarea, true as isaddress,
2477 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2478 0 as distance, country_code, postcode
2480 where place_id = for_place_id
2482 --RAISE WARNING '%',location;
2483 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2484 searchcountrycode := location.country_code;
2486 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2487 location.isaddress := FALSE;
2489 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2490 searchpostcode := location.postcode;
2492 IF location.rank_address = 4 AND location.isaddress THEN
2495 IF location.rank_address < 4 AND NOT hadcountry THEN
2496 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2497 IF countryname IS NOT NULL THEN
2498 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2499 RETURN NEXT countrylocation;
2502 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2503 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2504 location.distance)::addressline;
2505 RETURN NEXT countrylocation;
2506 found := location.rank_address;
2510 select placex.place_id, osm_type, osm_id,
2511 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2512 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2513 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2514 admin_level, fromarea, isaddress,
2515 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,
2516 distance,country_code,postcode
2517 from place_addressline join placex on (address_place_id = placex.place_id)
2518 where place_addressline.place_id = for_place_id
2519 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2520 and address_place_id != for_place_id
2521 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2522 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2524 --RAISE WARNING '%',location;
2525 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2526 searchcountrycode := location.country_code;
2528 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2529 location.isaddress := FALSE;
2531 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL and location.postcode not similar to '%(,|;)%' THEN
2532 searchpostcode := location.postcode;
2534 IF location.rank_address = 4 AND location.isaddress THEN
2537 IF location.rank_address < 4 AND NOT hadcountry THEN
2538 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2539 IF countryname IS NOT NULL THEN
2540 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2541 RETURN NEXT countrylocation;
2544 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2545 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2546 location.distance)::addressline;
2547 RETURN NEXT countrylocation;
2548 found := location.rank_address;
2552 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2553 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2554 IF countryname IS NOT NULL THEN
2555 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2556 RETURN NEXT location;
2560 IF searchcountrycode IS NOT NULL THEN
2561 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2562 RETURN NEXT location;
2565 IF searchhousename IS NOT NULL THEN
2566 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2567 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2568 RETURN NEXT location;
2571 IF searchhousenumber IS NOT NULL THEN
2572 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2573 RETURN NEXT location;
2576 IF searchpostcode IS NOT NULL THEN
2577 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2578 RETURN NEXT location;
2587 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2593 ELSEIF rank < 4 THEN
2595 ELSEIF rank < 8 THEN
2597 ELSEIF rank < 12 THEN
2599 ELSEIF rank < 16 THEN
2601 ELSEIF rank = 16 THEN
2603 ELSEIF rank = 17 THEN
2604 RETURN 'Town / Island';
2605 ELSEIF rank = 18 THEN
2606 RETURN 'Village / Hamlet';
2607 ELSEIF rank = 20 THEN
2609 ELSEIF rank = 21 THEN
2610 RETURN 'Postcode Area';
2611 ELSEIF rank = 22 THEN
2612 RETURN 'Croft / Farm / Locality / Islet';
2613 ELSEIF rank = 23 THEN
2614 RETURN 'Postcode Area';
2615 ELSEIF rank = 25 THEN
2616 RETURN 'Postcode Point';
2617 ELSEIF rank = 26 THEN
2618 RETURN 'Street / Major Landmark';
2619 ELSEIF rank = 27 THEN
2620 RETURN 'Minory Street / Path';
2621 ELSEIF rank = 28 THEN
2622 RETURN 'House / Building';
2624 RETURN 'Other: '||rank;
2631 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2637 ELSEIF rank < 2 THEN
2639 ELSEIF rank < 4 THEN
2641 ELSEIF rank = 5 THEN
2643 ELSEIF rank < 8 THEN
2645 ELSEIF rank < 12 THEN
2647 ELSEIF rank < 16 THEN
2649 ELSEIF rank = 16 THEN
2651 ELSEIF rank = 17 THEN
2652 RETURN 'Town / Village / Hamlet';
2653 ELSEIF rank = 20 THEN
2655 ELSEIF rank = 21 THEN
2656 RETURN 'Postcode Area';
2657 ELSEIF rank = 22 THEN
2658 RETURN 'Croft / Farm / Locality / Islet';
2659 ELSEIF rank = 23 THEN
2660 RETURN 'Postcode Area';
2661 ELSEIF rank = 25 THEN
2662 RETURN 'Postcode Point';
2663 ELSEIF rank = 26 THEN
2664 RETURN 'Street / Major Landmark';
2665 ELSEIF rank = 27 THEN
2666 RETURN 'Minory Street / Path';
2667 ELSEIF rank = 28 THEN
2668 RETURN 'House / Building';
2670 RETURN 'Other: '||rank;
2677 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2678 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2683 place_centroid GEOMETRY;
2684 out_partition INTEGER;
2685 out_parent_place_id BIGINT;
2687 address_street_word_id INTEGER;
2692 place_centroid := ST_Centroid(pointgeo);
2693 out_partition := get_partition(in_countrycode);
2694 out_parent_place_id := null;
2696 address_street_word_id := get_name_id(make_standard_name(in_street));
2697 IF address_street_word_id IS NOT NULL THEN
2698 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2699 out_parent_place_id := location.place_id;
2703 IF out_parent_place_id IS NULL THEN
2704 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2705 out_parent_place_id := location.place_id;
2709 out_postcode := in_postcode;
2710 IF out_postcode IS NULL THEN
2711 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2713 -- XXX look into postcode table
2716 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2717 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2718 newpoints := newpoints + 1;
2725 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2732 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2733 IF members[i+1] = member THEN
2734 result := result || members[i];
2743 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2749 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2750 IF members[i+1] = ANY(memberLabels) THEN
2751 RETURN NEXT members[i];
2760 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2761 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2763 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2764 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
2765 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2766 ), '') AS bytea), 'UTF8');
2768 LANGUAGE SQL IMMUTABLE STRICT;
2770 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2774 RETURN decode_url_part(p);
2776 WHEN others THEN return null;
2779 LANGUAGE plpgsql IMMUTABLE;
2781 DROP TYPE wikipedia_article_match CASCADE;
2782 create type wikipedia_article_match as (
2788 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2794 wiki_article_title TEXT;
2795 wiki_article_language TEXT;
2796 result wikipedia_article_match;
2798 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'];
2800 WHILE langs[i] IS NOT NULL LOOP
2801 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2802 IF wiki_article is not null THEN
2803 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2804 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2805 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2806 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2807 wiki_article := replace(wiki_article,' ','_');
2808 IF strpos(wiki_article, ':') IN (3,4) THEN
2809 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2810 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2812 wiki_article_title := trim(wiki_article);
2813 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;
2816 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2817 from wikipedia_article
2818 where language = wiki_article_language and
2819 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2821 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2822 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2823 where wikipedia_redirect.language = wiki_article_language and
2824 (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'\\',''))
2825 order by importance desc limit 1 INTO result;
2827 IF result.language is not null THEN
2838 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2839 RETURNS SETOF GEOMETRY
2853 remainingdepth INTEGER;
2858 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2860 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2861 RETURN NEXT geometry;
2865 remainingdepth := maxdepth - 1;
2866 area := ST_AREA(geometry);
2867 IF remainingdepth < 1 OR area < maxarea THEN
2868 RETURN NEXT geometry;
2872 xmin := st_xmin(geometry);
2873 xmax := st_xmax(geometry);
2874 ymin := st_ymin(geometry);
2875 ymax := st_ymax(geometry);
2876 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2878 -- if the geometry completely covers the box don't bother to slice any more
2879 IF ST_AREA(secbox) = area THEN
2880 RETURN NEXT geometry;
2884 xmid := (xmin+xmax)/2;
2885 ymid := (ymin+ymax)/2;
2888 FOR seg IN 1..4 LOOP
2891 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2894 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2897 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2900 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2903 IF st_intersects(geometry, secbox) THEN
2904 secgeo := st_intersection(geometry, secbox);
2905 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2906 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2907 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2909 RETURN NEXT geo.geom;
2921 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2922 RETURNS SETOF GEOMETRY
2927 -- 10000000000 is ~~ 1x1 degree
2928 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2929 RETURN NEXT geo.geom;
2937 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2941 osmtype character(1);
2945 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2946 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2947 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2948 -- force delete from place/placex by making it a very small geometry
2949 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;
2950 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2957 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2965 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2966 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2967 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2968 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2969 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2970 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2971 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'));
2972 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2973 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'));
2979 ELSEIF rank < 18 THEN
2981 ELSEIF rank < 20 THEN
2983 ELSEIF rank = 21 THEN
2985 ELSEIF rank < 24 THEN
2987 ELSEIF rank < 26 THEN
2988 diameter := 0.002; -- 100 to 200 meters
2989 ELSEIF rank < 28 THEN
2990 diameter := 0.001; -- 50 to 100 meters
2992 IF diameter > 0 THEN
2994 -- roads may cause reparenting for >27 rank places
2995 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2996 ELSEIF rank >= 16 THEN
2997 -- up to rank 16, street-less addresses may need reparenting
2998 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');
3000 -- for all other places the search terms may change as well
3001 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);