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
621 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
622 postcode := upper(trim (both ' ' from in_postcode));
625 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
626 centroid := ST_Centroid(geometry);
628 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
629 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
635 IF rank_address = 0 THEN
637 ELSEIF rank_search <= 14 THEN
639 ELSEIF rank_search <= 15 THEN
641 ELSEIF rank_search <= 16 THEN
643 ELSEIF rank_search <= 17 THEN
645 ELSEIF rank_search <= 21 THEN
647 ELSEIF rank_search = 25 THEN
651 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
653 secgeo := ST_Buffer(geometry, diameter);
654 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
664 -- find the parent road of the cut road parts
665 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
666 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
671 parent_place_id BIGINT;
672 address_street_word_ids INTEGER[];
678 addr_street = street;
681 IF addr_street is null and addr_place is null THEN
682 select nodes from planet_osm_ways where id = wayid INTO waynodes;
683 FOR location IN SELECT placex.address from placex
684 where osm_type = 'N' and osm_id = ANY(waynodes)
685 and placex.address is not null
686 and (placex.address ? 'street' or placex.address ? 'place')
687 and indexed_status < 100
689 addr_street = location.address->'street';
690 addr_place = location.address->'place';
694 IF addr_street IS NOT NULL THEN
695 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
696 IF address_street_word_ids IS NOT NULL THEN
697 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
698 parent_place_id := location.place_id;
703 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
704 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
705 IF address_street_word_ids IS NOT NULL THEN
706 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
707 parent_place_id := location.place_id;
712 IF parent_place_id is null THEN
713 FOR location IN SELECT place_id FROM placex
714 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
715 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
716 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
717 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
719 parent_place_id := location.place_id;
723 IF parent_place_id is null THEN
727 RETURN parent_place_id;
733 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
736 NEW.place_id := nextval('seq_place');
737 NEW.indexed_date := now();
739 IF NEW.indexed_status IS NULL THEN
740 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
741 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
742 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
746 NEW.indexed_status := 1; --STATUS_NEW
747 NEW.country_code := lower(get_country_code(NEW.linegeo));
749 NEW.partition := get_partition(NEW.country_code);
750 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
759 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
765 country_code VARCHAR(2);
766 default_language VARCHAR(10);
771 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
773 NEW.place_id := nextval('seq_place');
774 NEW.indexed_status := 1; --STATUS_NEW
776 NEW.country_code := lower(get_country_code(NEW.geometry));
778 NEW.partition := get_partition(NEW.country_code);
779 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
781 -- copy 'name' to or from the default language (if there is a default language)
782 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
783 default_language := get_country_language_code(NEW.country_code);
784 IF default_language IS NOT NULL THEN
785 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
786 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
787 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
788 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
793 IF NEW.osm_type = 'X' THEN
794 -- E'X'ternal records should already be in the right format so do nothing
796 NEW.rank_search := 30;
797 NEW.rank_address := NEW.rank_search;
799 -- By doing in postgres we have the country available to us - currently only used for postcode
800 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
802 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
803 -- most likely just a part of a multipolygon postcode boundary, throw it away
807 NEW.name := hstore('ref', NEW.postcode);
809 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
810 INTO NEW.rank_search, NEW.rank_address;
812 ELSEIF NEW.class = 'place' THEN
813 IF NEW.type in ('continent') THEN
814 NEW.rank_search := 2;
815 NEW.rank_address := NEW.rank_search;
816 NEW.country_code := NULL;
817 ELSEIF NEW.type in ('sea') THEN
818 NEW.rank_search := 2;
819 NEW.rank_address := 0;
820 NEW.country_code := NULL;
821 ELSEIF NEW.type in ('country') THEN
822 NEW.rank_search := 4;
823 NEW.rank_address := NEW.rank_search;
824 ELSEIF NEW.type in ('state') THEN
825 NEW.rank_search := 8;
826 NEW.rank_address := NEW.rank_search;
827 ELSEIF NEW.type in ('region') THEN
828 NEW.rank_search := 18; -- dropped from previous value of 10
829 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
830 ELSEIF NEW.type in ('county') THEN
831 NEW.rank_search := 12;
832 NEW.rank_address := NEW.rank_search;
833 ELSEIF NEW.type in ('city') THEN
834 NEW.rank_search := 16;
835 NEW.rank_address := NEW.rank_search;
836 ELSEIF NEW.type in ('island') THEN
837 NEW.rank_search := 17;
838 NEW.rank_address := 0;
839 ELSEIF NEW.type in ('town') THEN
840 NEW.rank_search := 18;
841 NEW.rank_address := 16;
842 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
843 NEW.rank_search := 19;
844 NEW.rank_address := 16;
845 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
846 NEW.rank_search := 20;
847 NEW.rank_address := NEW.rank_search;
848 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
849 NEW.rank_search := 20;
850 NEW.rank_address := 0;
851 -- Irish townlands, tagged as place=locality and locality=townland
852 IF (NEW.extratags -> 'locality') = 'townland' THEN
853 NEW.rank_address := 20;
855 ELSEIF NEW.type in ('neighbourhood') THEN
856 NEW.rank_search := 22;
857 NEW.rank_address := 22;
858 ELSEIF NEW.type in ('house','building') THEN
859 NEW.rank_search := 30;
860 NEW.rank_address := NEW.rank_search;
861 ELSEIF NEW.type in ('houses') THEN
862 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
863 NEW.rank_search := 28;
864 NEW.rank_address := 0;
867 ELSEIF NEW.class = 'boundary' THEN
868 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
869 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
872 NEW.rank_search := NEW.admin_level * 2;
873 IF NEW.type = 'administrative' THEN
874 NEW.rank_address := NEW.rank_search;
876 NEW.rank_address := 0;
878 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
879 NEW.rank_search := 22;
880 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
881 NEW.rank_address := NEW.rank_search;
883 NEW.rank_address := 0;
885 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
886 NEW.rank_search := 18;
887 NEW.rank_address := 0;
888 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
889 NEW.rank_search := 4;
890 NEW.rank_address := NEW.rank_search;
891 -- any feature more than 5 square miles is probably worth indexing
892 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
893 NEW.rank_search := 22;
894 NEW.rank_address := 0;
895 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
897 ELSEIF NEW.class = 'waterway' THEN
898 IF NEW.osm_type = 'R' THEN
899 NEW.rank_search := 16;
901 NEW.rank_search := 17;
903 NEW.rank_address := 0;
904 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
905 NEW.rank_search := 27;
906 NEW.rank_address := NEW.rank_search;
907 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
908 NEW.rank_search := 26;
909 NEW.rank_address := NEW.rank_search;
910 ELSEIF NEW.class = 'mountain_pass' THEN
911 NEW.rank_search := 20;
912 NEW.rank_address := 0;
917 IF NEW.rank_search > 30 THEN
918 NEW.rank_search := 30;
921 IF NEW.rank_address > 30 THEN
922 NEW.rank_address := 30;
925 IF (NEW.extratags -> 'capital') = 'yes' THEN
926 NEW.rank_search := NEW.rank_search - 1;
929 -- a country code make no sense below rank 4 (country)
930 IF NEW.rank_search < 4 THEN
931 NEW.country_code := NULL;
934 -- Block import below rank 22
935 -- IF NEW.rank_search > 22 THEN
939 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
941 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
943 IF NEW.rank_address > 0 THEN
944 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
945 -- Performance: We just can't handle re-indexing for country level changes
946 IF st_area(NEW.geometry) < 1 THEN
947 -- mark items within the geometry for re-indexing
948 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
950 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
951 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
952 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'));
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'));
957 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
959 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
960 IF NEW.type='postcode' THEN
962 ELSEIF NEW.rank_search < 16 THEN
964 ELSEIF NEW.rank_search < 18 THEN
966 ELSEIF NEW.rank_search < 20 THEN
968 ELSEIF NEW.rank_search = 21 THEN
970 ELSEIF NEW.rank_search < 24 THEN
972 ELSEIF NEW.rank_search < 26 THEN
973 diameter := 0.002; -- 100 to 200 meters
974 ELSEIF NEW.rank_search < 28 THEN
975 diameter := 0.001; -- 50 to 100 meters
978 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
979 IF NEW.rank_search >= 26 THEN
980 -- roads may cause reparenting for >27 rank places
981 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
982 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
983 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
984 ELSEIF NEW.rank_search >= 16 THEN
985 -- up to rank 16, street-less addresses may need reparenting
986 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');
988 -- for all other places the search terms may change as well
989 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);
996 -- add to tables for special search
997 -- Note: won't work on initial import because the classtype tables
998 -- do not yet exist. It won't hurt either.
999 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1000 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1002 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1003 USING NEW.place_id, ST_Centroid(NEW.geometry);
1012 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1016 place_centroid GEOMETRY;
1020 startnumber INTEGER;
1025 sectiongeo GEOMETRY;
1030 IF OLD.indexed_status = 100 THEN
1031 delete from location_property_osmline where place_id = OLD.place_id;
1035 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1039 NEW.interpolationtype = NEW.address->'interpolation';
1041 place_centroid := ST_PointOnSurface(NEW.linegeo);
1042 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1043 NEW.address->'place',
1044 NEW.partition, place_centroid, NEW.linegeo);
1047 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1048 NEW.postcode = NEW.address->'postcode';
1051 -- if the line was newly inserted, split the line as necessary
1052 IF OLD.indexed_status = 1 THEN
1053 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1055 IF array_upper(waynodes, 1) IS NULL THEN
1059 linegeo := NEW.linegeo;
1060 startnumber := NULL;
1061 postcode := NEW.postcode;
1063 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1065 select osm_id, address, geometry
1066 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1067 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1068 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1069 IF nextnode.osm_id IS NOT NULL THEN
1070 --RAISE NOTICE 'place_id is not null';
1071 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1072 -- Make sure that the point is actually on the line. That might
1073 -- be a bit paranoid but ensures that the algorithm still works
1074 -- should osm2pgsql attempt to repair geometries.
1075 splitline := split_line_on_node(linegeo, nextnode.geometry);
1076 sectiongeo := ST_GeometryN(splitline, 1);
1077 linegeo := ST_GeometryN(splitline, 2);
1079 sectiongeo = linegeo;
1081 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1083 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1084 AND startnumber != endnumber
1085 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1087 IF (startnumber > endnumber) THEN
1088 housenum := endnumber;
1089 endnumber := startnumber;
1090 startnumber := housenum;
1091 sectiongeo := ST_Reverse(sectiongeo);
1094 seg_postcode := coalesce(postcode,
1095 prevnode.address->'postcode',
1096 nextnode.address->'postcode');
1098 IF NEW.startnumber IS NULL THEN
1099 NEW.startnumber := startnumber;
1100 NEW.endnumber := endnumber;
1101 NEW.linegeo := sectiongeo;
1102 NEW.postcode := seg_postcode;
1104 insert into location_property_osmline
1105 (linegeo, partition, osm_id, parent_place_id,
1106 startnumber, endnumber, interpolationtype,
1107 address, postcode, country_code,
1108 geometry_sector, indexed_status)
1109 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1110 startnumber, endnumber, NEW.interpolationtype,
1111 NEW.address, seg_postcode,
1112 NEW.country_code, NEW.geometry_sector, 0);
1116 -- early break if we are out of line string,
1117 -- might happen when a line string loops back on itself
1118 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1122 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1123 prevnode := nextnode;
1128 -- marking descendants for reparenting is not needed, because there are
1129 -- actually no descendants for interpolation lines
1135 -- Trigger for updates of location_postcode
1137 -- Computes the parent object the postcode most likely refers to.
1138 -- This will be the place that determines the address displayed when
1139 -- searching for this postcode.
1140 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1147 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1151 NEW.indexed_date = now();
1153 partition := get_partition(NEW.country_code);
1155 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1156 INTO NEW.rank_search, NEW.rank_address;
1158 NEW.parent_place_id = 0;
1161 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1162 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1164 NEW.parent_place_id = location.place_id;
1172 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1177 place_centroid GEOMETRY;
1179 search_maxdistance FLOAT[];
1180 search_mindistance FLOAT[];
1181 address_havelevel BOOLEAN[];
1188 relation_members TEXT[];
1190 linkedplacex RECORD;
1191 search_diameter FLOAT;
1192 search_prevdiameter FLOAT;
1193 search_maxrank INTEGER;
1194 address_maxrank INTEGER;
1195 address_street_word_id INTEGER;
1196 address_street_word_ids INTEGER[];
1197 parent_place_id_rank BIGINT;
1205 location_rank_search INTEGER;
1206 location_distance FLOAT;
1207 location_parent GEOMETRY;
1208 location_isaddress BOOLEAN;
1209 location_keywords INTEGER[];
1211 default_language TEXT;
1212 name_vector INTEGER[];
1213 nameaddress_vector INTEGER[];
1215 linked_node_id BIGINT;
1216 linked_importance FLOAT;
1217 linked_wikipedia TEXT;
1222 IF OLD.indexed_status = 100 THEN
1223 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1224 delete from placex where place_id = OLD.place_id;
1228 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1232 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1234 NEW.indexed_date = now();
1236 result := deleteSearchName(NEW.partition, NEW.place_id);
1237 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1238 result := deleteRoad(NEW.partition, NEW.place_id);
1239 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1240 UPDATE placex set linked_place_id = null, indexed_status = 2
1241 where linked_place_id = NEW.place_id;
1242 -- update not necessary for osmline, cause linked_place_id does not exist
1244 IF NEW.linked_place_id is not null THEN
1245 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1249 --DEBUG: RAISE WARNING 'Copy over address tags';
1250 IF NEW.address is not NULL THEN
1251 IF NEW.address ? 'conscriptionnumber' THEN
1252 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1253 IF NEW.address ? 'streetnumber' THEN
1254 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1255 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1257 NEW.housenumber := NEW.address->'conscriptionnumber';
1259 ELSEIF NEW.address ? 'streetnumber' THEN
1260 NEW.housenumber := NEW.address->'streetnumber';
1261 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1262 ELSEIF NEW.address ? 'housenumber' THEN
1263 NEW.housenumber := NEW.address->'housenumber';
1264 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1267 addr_street = NEW.address->'street';
1268 addr_place = NEW.address->'place';
1271 -- Speed up searches - just use the centroid of the feature
1272 -- cheaper but less acurate
1273 place_centroid := ST_PointOnSurface(NEW.geometry);
1274 NEW.centroid := null;
1275 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1277 -- recalculate country and partition
1278 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1279 -- for countries, believe the mapped country code,
1280 -- so that we remain in the right partition if the boundaries
1282 NEW.country_code := lower(NEW.address->'country');
1283 NEW.partition := get_partition(lower(NEW.country_code));
1284 IF NEW.partition = 0 THEN
1285 NEW.country_code := lower(get_country_code(place_centroid));
1286 NEW.partition := get_partition(NEW.country_code);
1289 IF NEW.rank_search >= 4 THEN
1290 NEW.country_code := lower(get_country_code(place_centroid));
1292 NEW.country_code := NULL;
1294 NEW.partition := get_partition(NEW.country_code);
1296 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1298 -- waterway ways are linked when they are part of a relation and have the same class/type
1299 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1300 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1302 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1303 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1304 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1305 FOR linked_node_id IN SELECT place_id FROM placex
1306 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1307 and class = NEW.class and type = NEW.type
1308 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1310 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1315 --DEBUG: RAISE WARNING 'Waterway processed';
1318 -- Adding ourselves to the list simplifies address calculations later
1319 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1320 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1322 -- What level are we searching from
1323 search_maxrank := NEW.rank_search;
1325 -- Thought this wasn't needed but when we add new languages to the country_name table
1326 -- we need to update the existing names
1327 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1328 default_language := get_country_language_code(NEW.country_code);
1329 IF default_language IS NOT NULL THEN
1330 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1331 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1332 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1333 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1337 --DEBUG: RAISE WARNING 'Local names updated';
1339 -- Initialise the name vector using our name
1340 name_vector := make_keywords(NEW.name);
1341 nameaddress_vector := '{}'::int[];
1344 address_havelevel[i] := false;
1347 NEW.importance := null;
1348 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1349 IF NEW.importance IS NULL THEN
1350 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;
1353 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1355 -- ---------------------------------------------------------------------------
1356 -- For low level elements we inherit from our parent road
1357 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1359 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1361 -- We won't get a better centroid, besides these places are too small to care
1362 NEW.centroid := place_centroid;
1364 NEW.parent_place_id := null;
1366 -- if we have a POI and there is no address information,
1367 -- see if we can get it from a surrounding building
1368 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1369 AND NEW.housenumber IS NULL THEN
1370 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1371 and address is not null
1372 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1373 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1376 NEW.housenumber := location.address->'housenumber';
1377 addr_street := location.address->'street';
1378 addr_place := location.address->'place';
1379 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1383 -- We have to find our parent road.
1384 -- Copy data from linked items (points on ways, addr:street links, relations)
1386 -- Is this object part of a relation?
1387 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1389 -- At the moment we only process one type of relation - associatedStreet
1390 IF relation.tags @> ARRAY['associatedStreet'] THEN
1391 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1392 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1393 --RAISE WARNING 'node in relation %',relation;
1394 SELECT place_id from placex where osm_type = 'W'
1395 and osm_id = substring(relation.members[i],2,200)::bigint
1396 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1401 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1403 -- Note that addr:street links can only be indexed once the street itself is indexed
1404 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1405 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1406 IF address_street_word_ids IS NOT NULL THEN
1407 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1408 NEW.parent_place_id := location.place_id;
1412 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1414 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1415 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1416 IF address_street_word_ids IS NOT NULL THEN
1417 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1418 NEW.parent_place_id := location.place_id;
1422 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1424 -- Is this node part of an interpolation?
1425 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1427 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1428 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1431 NEW.parent_place_id := location.parent_place_id;
1434 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1436 -- Is this node part of a way?
1437 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1439 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
1440 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)
1442 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1444 -- Way IS a road then we are on it - that must be our road
1445 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1446 --RAISE WARNING 'node in way that is a street %',location;
1447 NEW.parent_place_id := location.place_id;
1449 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1451 -- If the way mentions a street or place address, try that for parenting.
1452 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1453 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1454 IF address_street_word_ids IS NOT NULL THEN
1455 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1456 NEW.parent_place_id := linkedplacex.place_id;
1460 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1462 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1463 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1464 IF address_street_word_ids IS NOT NULL THEN
1465 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1466 NEW.parent_place_id := linkedplacex.place_id;
1470 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1472 -- Is the WAY part of a relation
1473 IF NEW.parent_place_id IS NULL THEN
1474 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1476 -- At the moment we only process one type of relation - associatedStreet
1477 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1478 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1479 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1480 --RAISE WARNING 'node in way that is in a relation %',relation;
1481 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1482 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1488 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1494 -- Still nothing, just use the nearest road
1495 IF NEW.parent_place_id IS NULL THEN
1496 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1497 NEW.parent_place_id := location.place_id;
1500 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1503 -- If we didn't find any road fallback to standard method
1504 IF NEW.parent_place_id IS NOT NULL THEN
1506 -- Get the details of the parent road
1507 select * from search_name where place_id = NEW.parent_place_id INTO location;
1508 NEW.country_code := location.country_code;
1509 --DEBUG: RAISE WARNING 'Got parent details from search name';
1511 -- determine postcode
1512 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1513 NEW.postcode = NEW.address->'postcode';
1515 SELECT postcode FROM placex WHERE place_id = parent_place_id INTO NEW.postcode;
1517 IF NEW.postcode is null THEN
1518 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1521 -- Merge the postcode into the parent's address if necessary
1522 IF NEW.postcode IS NOT NULL THEN
1523 --DEBUG: RAISE WARNING 'Merging postcode into parent';
1524 isin_tokens := '{}'::int[];
1525 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1526 IF address_street_word_id is not null
1527 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1528 isin_tokens := isin_tokens || address_street_word_id;
1530 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1531 IF address_street_word_id is not null
1532 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1533 isin_tokens := isin_tokens || address_street_word_id;
1535 IF isin_tokens != '{}'::int[] THEN
1537 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1538 WHERE place_id = NEW.parent_place_id;
1542 -- If there is no name it isn't searchable, don't bother to create a search record
1543 IF NEW.name is NULL THEN
1544 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1548 -- Merge address from parent
1549 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1550 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1552 -- Performance, it would be more acurate to do all the rest of the import
1553 -- process but it takes too long
1554 -- Just be happy with inheriting from parent road only
1556 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1557 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1558 --DEBUG: RAISE WARNING 'Place added to location table';
1561 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);
1562 --DEBUG: RAISE WARNING 'Place added to search table';
1569 -- ---------------------------------------------------------------------------
1571 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1573 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1575 -- see if we have any special relation members
1576 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1577 --DEBUG: RAISE WARNING 'Got relation members';
1579 IF relation_members IS NOT NULL THEN
1580 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1581 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1583 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1584 and osm_id = substring(relMember.member,2,10000)::bigint
1585 and class = 'place' order by rank_search desc limit 1 LOOP
1587 -- If we don't already have one use this as the centre point of the geometry
1588 IF NEW.centroid IS NULL THEN
1589 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1592 -- merge in the label name, re-init word vector
1593 IF NOT linkedPlacex.name IS NULL THEN
1594 NEW.name := linkedPlacex.name || NEW.name;
1595 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1598 -- merge in extra tags
1599 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1601 -- mark the linked place (excludes from search results)
1602 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1604 -- keep a note of the node id in case we need it for wikipedia in a bit
1605 linked_node_id := linkedPlacex.osm_id;
1606 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1607 --DEBUG: RAISE WARNING 'Linked label member';
1612 IF NEW.centroid IS NULL THEN
1614 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1615 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1617 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1618 and osm_id = substring(relMember.member,2,10000)::bigint
1619 and class = 'place' order by rank_search desc limit 1 LOOP
1621 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1622 -- But that can be fixed by explicitly setting the label in the data
1623 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1624 AND NEW.rank_address = linkedPlacex.rank_address THEN
1626 -- If we don't already have one use this as the centre point of the geometry
1627 IF NEW.centroid IS NULL THEN
1628 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1631 -- merge in the name, re-init word vector
1632 IF NOT linkedPlacex.name IS NULL THEN
1633 NEW.name := linkedPlacex.name || NEW.name;
1634 name_vector := make_keywords(NEW.name);
1637 -- merge in extra tags
1638 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1640 -- mark the linked place (excludes from search results)
1641 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1643 -- keep a note of the node id in case we need it for wikipedia in a bit
1644 linked_node_id := linkedPlacex.osm_id;
1645 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1646 --DEBUG: RAISE WARNING 'Linked admin_center';
1658 -- Name searches can be done for ways as well as relations
1659 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1661 -- not found one yet? how about doing a name search
1662 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1664 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1665 FOR linkedPlacex IN select placex.* from placex WHERE
1666 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1667 AND placex.rank_address = NEW.rank_address
1668 AND placex.place_id != NEW.place_id
1669 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1670 AND st_covers(NEW.geometry, placex.geometry)
1672 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1673 -- If we don't already have one use this as the centre point of the geometry
1674 IF NEW.centroid IS NULL THEN
1675 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1678 -- merge in the name, re-init word vector
1679 NEW.name := linkedPlacex.name || NEW.name;
1680 name_vector := make_keywords(NEW.name);
1682 -- merge in extra tags
1683 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1685 -- mark the linked place (excludes from search results)
1686 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1688 -- keep a note of the node id in case we need it for wikipedia in a bit
1689 linked_node_id := linkedPlacex.osm_id;
1690 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1691 --DEBUG: RAISE WARNING 'Linked named place';
1695 IF NEW.centroid IS NOT NULL THEN
1696 place_centroid := NEW.centroid;
1697 -- Place might have had only a name tag before but has now received translations
1698 -- from the linked place. Make sure a name tag for the default language exists in
1700 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1701 default_language := get_country_language_code(NEW.country_code);
1702 IF default_language IS NOT NULL THEN
1703 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1704 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1705 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1706 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1710 --DEBUG: RAISE WARNING 'Names updated from linked places';
1713 -- Use the maximum importance if a one could be computed from the linked object.
1714 IF linked_importance is not null AND
1715 (NEW.importance is null or NEW.importance < linked_importance) THEN
1716 NEW.importance = linked_importance;
1719 -- Still null? how about looking it up by the node id
1720 IF NEW.importance IS NULL THEN
1721 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1722 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;
1727 -- make sure all names are in the word table
1728 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1729 perform create_country(NEW.name, lower(NEW.country_code));
1730 --DEBUG: RAISE WARNING 'Country names updated';
1733 NEW.parent_place_id = 0;
1734 parent_place_id_rank = 0;
1737 -- convert isin to array of tokenids
1738 --DEBUG: RAISE WARNING 'Starting address search';
1739 isin_tokens := '{}'::int[];
1740 IF NEW.address IS NOT NULL THEN
1741 isin := avals(NEW.address);
1742 IF array_upper(isin, 1) IS NOT NULL THEN
1743 FOR i IN 1..array_upper(isin, 1) LOOP
1744 -- TODO further split terms with comma and semicolon
1745 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1746 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1747 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1748 isin_tokens := isin_tokens || address_street_word_id;
1751 -- merge word into address vector
1752 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1753 IF address_street_word_id IS NOT NULL THEN
1754 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1760 -- %NOTIGERDATA% IF 0 THEN
1761 -- for the USA we have an additional address table. Merge in zip codes from there too
1762 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1763 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1764 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1765 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1766 isin_tokens := isin_tokens || address_street_word_id;
1768 -- also merge in the single word version
1769 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1770 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1773 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1774 -- %NOTIGERDATA% END IF;
1776 -- RAISE WARNING 'ISIN: %', isin_tokens;
1778 -- Process area matches
1779 location_rank_search := 0;
1780 location_distance := 0;
1781 location_parent := NULL;
1782 -- added ourself as address already
1783 address_havelevel[NEW.rank_address] := true;
1784 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1786 SELECT * from getNearFeatures(NEW.partition,
1787 CASE WHEN NEW.rank_search >= 26
1788 AND NEW.rank_search < 30
1790 ELSE place_centroid END,
1791 search_maxrank, isin_tokens)
1793 IF location.rank_address != location_rank_search THEN
1794 location_rank_search := location.rank_address;
1795 IF location.isguess THEN
1796 location_distance := location.distance * 1.5;
1798 IF location.rank_address <= 12 THEN
1799 -- for county and above, if we have an area consider that exact
1800 -- (It would be nice to relax the constraint for places close to
1801 -- the boundary but we'd need the exact geometry for that. Too
1803 location_distance = 0;
1805 -- Below county level remain slightly fuzzy.
1806 location_distance := location.distance * 0.5;
1810 CONTINUE WHEN location.keywords <@ location_keywords;
1813 IF location.distance < location_distance OR NOT location.isguess THEN
1814 location_keywords := location.keywords;
1816 location_isaddress := NOT address_havelevel[location.rank_address];
1817 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1818 location_isaddress := ST_Contains(location_parent,location.centroid);
1821 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1822 -- Add it to the list of search terms
1823 IF location.rank_search > 4 THEN
1824 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1826 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1827 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1829 IF location_isaddress THEN
1830 -- add postcode if we have one
1831 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1832 IF location.postcode is not null THEN
1833 NEW.postcode = location.postcode;
1836 address_havelevel[location.rank_address] := true;
1837 IF NOT location.isguess THEN
1838 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1841 IF location.rank_address > parent_place_id_rank THEN
1842 NEW.parent_place_id = location.place_id;
1843 parent_place_id_rank = location.rank_address;
1848 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1853 --DEBUG: RAISE WARNING 'address computed';
1855 -- try using the isin value to find parent places
1856 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1857 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1858 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1859 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1861 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1863 --RAISE WARNING ' ISIN: %',location;
1865 IF location.rank_search > 4 THEN
1866 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1867 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1868 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1869 IF NEW.postcode is null AND location.postcode is not null
1870 AND NOT address_havelevel[location.rank_address] THEN
1871 NEW.postcode := location.postcode;
1874 address_havelevel[location.rank_address] := true;
1876 IF location.rank_address > parent_place_id_rank THEN
1877 NEW.parent_place_id = location.place_id;
1878 parent_place_id_rank = location.rank_address;
1887 --DEBUG: RAISE WARNING 'isin tokens processed';
1889 -- for long ways we should add search terms for the entire length
1890 IF st_length(NEW.geometry) > 0.05 THEN
1892 location_rank_search := 0;
1893 location_distance := 0;
1895 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1897 IF location.rank_address != location_rank_search THEN
1898 location_rank_search := location.rank_address;
1899 location_distance := location.distance * 1.5;
1902 IF location.rank_search > 4 AND location.distance < location_distance THEN
1904 -- Add it to the list of search terms
1905 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1906 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1907 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1914 --DEBUG: RAISE WARNING 'search terms for long ways added';
1916 IF NEW.address is not null AND NEW.address ? 'postcode'
1917 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1918 NEW.postcode := NEW.address->'postcode';
1921 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1922 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1925 -- if we have a name add this to the name search table
1926 IF NEW.name IS NOT NULL THEN
1928 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1929 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1930 --DEBUG: RAISE WARNING 'added to location (full)';
1933 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1934 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1935 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1938 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);
1939 --DEBUG: RAISE WARNING 'added to serach name (full)';
1943 -- If we've not managed to pick up a better one - default centroid
1944 IF NEW.centroid IS NULL THEN
1945 NEW.centroid := place_centroid;
1948 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1955 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1961 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1963 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1964 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1965 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1966 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1968 IF OLD.rank_address < 30 THEN
1970 -- mark everything linked to this place for re-indexing
1971 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1972 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1973 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1975 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1976 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1978 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1979 b := deleteRoad(OLD.partition, OLD.place_id);
1981 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1982 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1983 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1984 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1985 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1989 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1991 IF OLD.rank_address < 26 THEN
1992 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1995 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1997 IF OLD.name is not null THEN
1998 b := deleteSearchName(OLD.partition, OLD.place_id);
2001 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2003 DELETE FROM place_addressline where place_id = OLD.place_id;
2005 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2007 -- remove from tables for special search
2008 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2009 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2011 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2014 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2022 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2028 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2030 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2031 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2032 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;
2034 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2040 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;
2042 -- interpolations are special
2043 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2044 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2053 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2058 existingplacex RECORD;
2059 existingline RECORD;
2060 existinggeometry GEOMETRY;
2061 existingplace_id BIGINT;
2066 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2067 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2068 -- filter wrong tupels
2069 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
2070 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2071 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2072 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2076 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2077 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2078 -- Have we already done this place?
2079 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;
2081 -- Get the existing place_id
2082 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2084 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2085 IF existing.osm_type IS NULL THEN
2086 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2089 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2090 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2092 -- 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)
2093 IF existingline.osm_id IS NOT NULL THEN
2094 delete from location_property_osmline where osm_id = NEW.osm_id;
2097 -- for interpolations invalidate all nodes on the line
2098 update placex p set indexed_status = 2
2099 from planet_osm_ways w
2100 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2103 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2104 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2107 IF existing.osm_type IS NULL THEN
2111 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2112 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2113 OR existing.geometry::text != NEW.geometry::text
2118 address = NEW.address,
2119 extratags = NEW.extratags,
2120 admin_level = NEW.admin_level,
2121 geometry = NEW.geometry
2122 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2127 ELSE -- insert to placex
2129 -- Patch in additional country names
2130 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2131 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2132 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2133 IF existing.name IS NOT NULL THEN
2134 NEW.name = existing.name || NEW.name;
2138 -- Have we already done this place?
2139 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;
2141 -- Get the existing place_id
2142 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;
2144 -- Handle a place changing type by removing the old data
2145 -- My generated 'place' types are causing havok because they overlap with real keys
2146 -- TODO: move them to their own special purpose key/class to avoid collisions
2147 IF existing.osm_type IS NULL THEN
2148 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2151 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2152 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2155 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2156 AND st_area(existing.geometry) > 0.02
2157 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2158 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2160 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2161 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2162 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2166 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2167 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2169 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2170 IF existingplacex.osm_type IS NULL OR
2171 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2174 IF existingplacex.osm_type IS NOT NULL THEN
2175 -- sanity check: ignore admin_level changes on places with too many active children
2176 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2177 --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;
2178 --LIMIT INDEXING: IF i > 100000 THEN
2179 --LIMIT INDEXING: RETURN null;
2180 --LIMIT INDEXING: END IF;
2183 IF existing.osm_type IS NOT NULL THEN
2184 -- pathological case caused by the triggerless copy into place during initial import
2185 -- force delete even for large areas, it will be reinserted later
2186 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;
2187 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2190 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2191 insert into placex (osm_type, osm_id, class, type, name,
2192 admin_level, address, extratags, geometry)
2193 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2194 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2196 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2201 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2202 IF existing.geometry::text != NEW.geometry::text
2203 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2204 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2207 -- Get the version of the geometry actually used (in placex table)
2208 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;
2210 -- Performance limit
2211 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2213 -- 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
2214 update placex set indexed_status = 2 where indexed_status = 0 and
2215 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2216 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2217 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2219 update placex set indexed_status = 2 where indexed_status = 0 and
2220 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2221 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2222 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2229 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2230 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2231 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2232 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2233 OR existing.geometry::text != NEW.geometry::text
2238 address = NEW.address,
2239 extratags = NEW.extratags,
2240 admin_level = NEW.admin_level,
2241 geometry = NEW.geometry
2242 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2245 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2246 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2247 -- postcode was deleted, no longer retain in placex
2248 DELETE FROM placex where place_id = existingplacex.place_id;
2252 NEW.name := hstore('ref', NEW.address->'postcode');
2255 IF NEW.class in ('boundary')
2256 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2257 DELETE FROM placex where place_id = existingplacex.place_id;
2263 address = NEW.address,
2264 parent_place_id = null,
2265 extratags = NEW.extratags,
2266 admin_level = NEW.admin_level,
2268 geometry = NEW.geometry
2269 where place_id = existingplacex.place_id;
2271 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2272 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2273 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2274 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2275 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);
2278 -- linked places should get potential new naming and addresses
2279 IF existingplacex.linked_place_id is not NULL THEN
2282 extratags = p.extratags,
2285 where x.place_id = existingplacex.linked_place_id
2286 and x.indexed_status = 0
2287 and x.osm_type = p.osm_type
2288 and x.osm_id = p.osm_id
2289 and x.class = p.class;
2294 -- Abort the add (we modified the existing place instead)
2299 $$ LANGUAGE plpgsql;
2302 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2307 IF name is null THEN
2311 FOR j IN 1..array_upper(languagepref,1) LOOP
2312 IF name ? languagepref[j] THEN
2313 result := trim(name->languagepref[j]);
2314 IF result != '' THEN
2320 -- anything will do as a fallback - just take the first name type thing there is
2321 RETURN trim((avals(name))[1]);
2324 LANGUAGE plpgsql IMMUTABLE;
2326 --housenumber only needed for tiger data
2327 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2339 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2340 currresult := trim(get_name_by_language(location.name, languagepref));
2341 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2342 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2343 prevresult := currresult;
2347 RETURN array_to_string(result,', ');
2352 DROP TYPE IF EXISTS addressline CASCADE;
2353 create type addressline as (
2360 admin_level INTEGER,
2363 rank_address INTEGER,
2367 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2370 for_place_id BIGINT;
2375 countrylocation RECORD;
2376 searchcountrycode varchar(2);
2377 searchhousenumber TEXT;
2378 searchhousename HSTORE;
2379 searchrankaddress INTEGER;
2380 searchpostcode TEXT;
2386 -- first query osmline (interpolation lines)
2387 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2388 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2389 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2390 IF for_place_id IS NOT NULL THEN
2391 searchhousenumber = in_housenumber::text;
2394 --then query tiger data
2395 -- %NOTIGERDATA% IF 0 THEN
2396 IF for_place_id IS NULL THEN
2397 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2398 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2399 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2400 IF for_place_id IS NOT NULL THEN
2401 searchhousenumber = in_housenumber::text;
2404 -- %NOTIGERDATA% END IF;
2406 -- %NOAUXDATA% IF 0 THEN
2407 IF for_place_id IS NULL THEN
2408 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2409 WHERE place_id = in_place_id
2410 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2412 -- %NOAUXDATA% END IF;
2414 IF for_place_id IS NULL THEN
2415 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2416 WHERE place_id = in_place_id and rank_search > 27
2417 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2420 IF for_place_id IS NULL THEN
2421 select coalesce(linked_place_id, place_id), country_code,
2422 housenumber, rank_search, postcode, null
2423 from placex where place_id = in_place_id
2424 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2427 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2430 hadcountry := false;
2432 select placex.place_id, osm_type, osm_id, name,
2433 class, type, admin_level, true as isaddress,
2434 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2435 0 as distance, country_code, postcode
2437 where place_id = for_place_id
2439 --RAISE WARNING '%',location;
2440 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2441 searchcountrycode := location.country_code;
2443 IF location.type in ('postcode', 'postal_code') THEN
2444 location.isaddress := FALSE;
2445 ELSEIF location.rank_address = 4 THEN
2448 IF location.rank_address < 4 AND NOT hadcountry THEN
2449 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2450 IF countryname IS NOT NULL THEN
2451 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2452 RETURN NEXT countrylocation;
2455 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2456 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2457 location.distance)::addressline;
2458 RETURN NEXT countrylocation;
2459 found := location.rank_address;
2463 select placex.place_id, osm_type, osm_id, name,
2464 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2465 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2466 admin_level, fromarea, isaddress,
2467 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,
2468 distance,country_code,postcode
2469 from place_addressline join placex on (address_place_id = placex.place_id)
2470 where place_addressline.place_id = for_place_id
2471 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2472 and address_place_id != for_place_id
2473 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2474 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2476 --RAISE WARNING '%',location;
2477 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2478 searchcountrycode := location.country_code;
2480 IF location.type in ('postcode', 'postal_code') THEN
2481 location.isaddress := FALSE;
2483 IF location.rank_address = 4 AND location.isaddress THEN
2486 IF location.rank_address < 4 AND NOT hadcountry THEN
2487 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2488 IF countryname IS NOT NULL THEN
2489 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2490 RETURN NEXT countrylocation;
2493 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2494 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2495 location.distance)::addressline;
2496 RETURN NEXT countrylocation;
2497 found := location.rank_address;
2501 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2502 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2503 IF countryname IS NOT NULL THEN
2504 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2505 RETURN NEXT location;
2509 IF searchcountrycode IS NOT NULL THEN
2510 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2511 RETURN NEXT location;
2514 IF searchhousename IS NOT NULL THEN
2515 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2516 RETURN NEXT location;
2519 IF searchhousenumber IS NOT NULL THEN
2520 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2521 RETURN NEXT location;
2524 IF searchpostcode IS NOT NULL THEN
2525 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2526 RETURN NEXT location;
2535 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2541 ELSEIF rank < 4 THEN
2543 ELSEIF rank < 8 THEN
2545 ELSEIF rank < 12 THEN
2547 ELSEIF rank < 16 THEN
2549 ELSEIF rank = 16 THEN
2551 ELSEIF rank = 17 THEN
2552 RETURN 'Town / Island';
2553 ELSEIF rank = 18 THEN
2554 RETURN 'Village / Hamlet';
2555 ELSEIF rank = 20 THEN
2557 ELSEIF rank = 21 THEN
2558 RETURN 'Postcode Area';
2559 ELSEIF rank = 22 THEN
2560 RETURN 'Croft / Farm / Locality / Islet';
2561 ELSEIF rank = 23 THEN
2562 RETURN 'Postcode Area';
2563 ELSEIF rank = 25 THEN
2564 RETURN 'Postcode Point';
2565 ELSEIF rank = 26 THEN
2566 RETURN 'Street / Major Landmark';
2567 ELSEIF rank = 27 THEN
2568 RETURN 'Minory Street / Path';
2569 ELSEIF rank = 28 THEN
2570 RETURN 'House / Building';
2572 RETURN 'Other: '||rank;
2579 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2585 ELSEIF rank < 2 THEN
2587 ELSEIF rank < 4 THEN
2589 ELSEIF rank = 5 THEN
2591 ELSEIF rank < 8 THEN
2593 ELSEIF rank < 12 THEN
2595 ELSEIF rank < 16 THEN
2597 ELSEIF rank = 16 THEN
2599 ELSEIF rank = 17 THEN
2600 RETURN 'Town / Village / Hamlet';
2601 ELSEIF rank = 20 THEN
2603 ELSEIF rank = 21 THEN
2604 RETURN 'Postcode Area';
2605 ELSEIF rank = 22 THEN
2606 RETURN 'Croft / Farm / Locality / Islet';
2607 ELSEIF rank = 23 THEN
2608 RETURN 'Postcode Area';
2609 ELSEIF rank = 25 THEN
2610 RETURN 'Postcode Point';
2611 ELSEIF rank = 26 THEN
2612 RETURN 'Street / Major Landmark';
2613 ELSEIF rank = 27 THEN
2614 RETURN 'Minory Street / Path';
2615 ELSEIF rank = 28 THEN
2616 RETURN 'House / Building';
2618 RETURN 'Other: '||rank;
2625 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2626 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2631 place_centroid GEOMETRY;
2632 out_partition INTEGER;
2633 out_parent_place_id BIGINT;
2635 address_street_word_id INTEGER;
2640 place_centroid := ST_Centroid(pointgeo);
2641 out_partition := get_partition(in_countrycode);
2642 out_parent_place_id := null;
2644 address_street_word_id := get_name_id(make_standard_name(in_street));
2645 IF address_street_word_id IS NOT NULL THEN
2646 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2647 out_parent_place_id := location.place_id;
2651 IF out_parent_place_id IS NULL THEN
2652 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2653 out_parent_place_id := location.place_id;
2657 out_postcode := in_postcode;
2658 IF out_postcode IS NULL THEN
2659 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2661 -- XXX look into postcode table
2664 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2665 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2666 newpoints := newpoints + 1;
2673 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2680 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2681 IF members[i+1] = member THEN
2682 result := result || members[i];
2691 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2697 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2698 IF members[i+1] = ANY(memberLabels) THEN
2699 RETURN NEXT members[i];
2708 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2709 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2711 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2712 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
2713 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2714 ), '') AS bytea), 'UTF8');
2716 LANGUAGE SQL IMMUTABLE STRICT;
2718 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2722 RETURN decode_url_part(p);
2724 WHEN others THEN return null;
2727 LANGUAGE plpgsql IMMUTABLE;
2729 DROP TYPE wikipedia_article_match CASCADE;
2730 create type wikipedia_article_match as (
2736 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2742 wiki_article_title TEXT;
2743 wiki_article_language TEXT;
2744 result wikipedia_article_match;
2746 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'];
2748 WHILE langs[i] IS NOT NULL LOOP
2749 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2750 IF wiki_article is not null THEN
2751 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2752 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2753 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2754 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2755 wiki_article := replace(wiki_article,' ','_');
2756 IF strpos(wiki_article, ':') IN (3,4) THEN
2757 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2758 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2760 wiki_article_title := trim(wiki_article);
2761 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;
2764 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2765 from wikipedia_article
2766 where language = wiki_article_language and
2767 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2769 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2770 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2771 where wikipedia_redirect.language = wiki_article_language and
2772 (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'\\',''))
2773 order by importance desc limit 1 INTO result;
2775 IF result.language is not null THEN
2786 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2787 RETURNS SETOF GEOMETRY
2801 remainingdepth INTEGER;
2806 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2808 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2809 RETURN NEXT geometry;
2813 remainingdepth := maxdepth - 1;
2814 area := ST_AREA(geometry);
2815 IF remainingdepth < 1 OR area < maxarea THEN
2816 RETURN NEXT geometry;
2820 xmin := st_xmin(geometry);
2821 xmax := st_xmax(geometry);
2822 ymin := st_ymin(geometry);
2823 ymax := st_ymax(geometry);
2824 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2826 -- if the geometry completely covers the box don't bother to slice any more
2827 IF ST_AREA(secbox) = area THEN
2828 RETURN NEXT geometry;
2832 xmid := (xmin+xmax)/2;
2833 ymid := (ymin+ymax)/2;
2836 FOR seg IN 1..4 LOOP
2839 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2842 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2845 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2848 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2851 IF st_intersects(geometry, secbox) THEN
2852 secgeo := st_intersection(geometry, secbox);
2853 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2854 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2855 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2857 RETURN NEXT geo.geom;
2869 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2870 RETURNS SETOF GEOMETRY
2875 -- 10000000000 is ~~ 1x1 degree
2876 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2877 RETURN NEXT geo.geom;
2885 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2889 osmtype character(1);
2893 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2894 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2895 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2896 -- force delete from place/placex by making it a very small geometry
2897 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;
2898 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2905 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2913 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2914 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2915 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2916 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2917 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2918 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2919 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
2920 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2921 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'));
2927 ELSEIF rank < 18 THEN
2929 ELSEIF rank < 20 THEN
2931 ELSEIF rank = 21 THEN
2933 ELSEIF rank < 24 THEN
2935 ELSEIF rank < 26 THEN
2936 diameter := 0.002; -- 100 to 200 meters
2937 ELSEIF rank < 28 THEN
2938 diameter := 0.001; -- 50 to 100 meters
2940 IF diameter > 0 THEN
2942 -- roads may cause reparenting for >27 rank places
2943 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2944 ELSEIF rank >= 16 THEN
2945 -- up to rank 16, street-less addresses may need reparenting
2946 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');
2948 -- for all other places the search terms may change as well
2949 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);