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, 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 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, null, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_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 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, null, 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;
239 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
248 FOR item IN SELECT (each(src)).* LOOP
250 s := make_standard_name(item.value);
251 w := getorcreate_country(s, lookup_country_code);
253 words := regexp_split_to_array(item.value, E'[,;()]');
254 IF array_upper(words, 1) != 1 THEN
255 FOR j IN 1..array_upper(words, 1) LOOP
256 s := make_standard_name(words[j]);
258 w := getorcreate_country(s, lookup_country_code);
267 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
277 result := '{}'::INTEGER[];
279 FOR item IN SELECT (each(src)).* LOOP
281 s := make_standard_name(item.value);
283 w := getorcreate_name_id(s, item.value);
285 IF not(ARRAY[w] <@ result) THEN
286 result := result || w;
289 w := getorcreate_word_id(s);
291 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
292 result := result || w;
295 words := string_to_array(s, ' ');
296 IF array_upper(words, 1) IS NOT NULL THEN
297 FOR j IN 1..array_upper(words, 1) LOOP
298 IF (words[j] != '') THEN
299 w = getorcreate_word_id(words[j]);
300 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
301 result := result || w;
307 words := regexp_split_to_array(item.value, E'[,;()]');
308 IF array_upper(words, 1) != 1 THEN
309 FOR j IN 1..array_upper(words, 1) LOOP
310 s := make_standard_name(words[j]);
312 w := getorcreate_word_id(s);
313 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
314 result := result || w;
320 s := regexp_replace(item.value, '市$', '');
321 IF s != item.value THEN
322 s := make_standard_name(s);
324 w := getorcreate_name_id(s, item.value);
325 IF NOT (ARRAY[w] <@ result) THEN
326 result := result || w;
336 LANGUAGE plpgsql IMMUTABLE;
338 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
348 result := '{}'::INTEGER[];
350 s := make_standard_name(src);
351 w := getorcreate_name_id(s, src);
353 IF NOT (ARRAY[w] <@ result) THEN
354 result := result || w;
357 w := getorcreate_word_id(s);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
363 words := string_to_array(s, ' ');
364 IF array_upper(words, 1) IS NOT NULL THEN
365 FOR j IN 1..array_upper(words, 1) LOOP
366 IF (words[j] != '') THEN
367 w = getorcreate_word_id(words[j]);
368 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
369 result := result || w;
375 words := regexp_split_to_array(src, E'[,;()]');
376 IF array_upper(words, 1) != 1 THEN
377 FOR j IN 1..array_upper(words, 1) LOOP
378 s := make_standard_name(words[j]);
380 w := getorcreate_word_id(s);
381 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
382 result := result || w;
388 s := regexp_replace(src, '市$', '');
390 s := make_standard_name(s);
392 w := getorcreate_name_id(s, src);
393 IF NOT (ARRAY[w] <@ result) THEN
394 result := result || w;
402 LANGUAGE plpgsql IMMUTABLE;
404 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
407 place_centre GEOMETRY;
410 place_centre := ST_PointOnSurface(place);
412 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
414 -- Try for a OSM polygon
415 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
417 RETURN nearcountry.country_code;
420 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
422 -- Try for OSM fallback data
423 -- The order is to deal with places like HongKong that are 'states' within another polygon
424 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
426 RETURN nearcountry.country_code;
429 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
431 -- Natural earth data
432 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
434 RETURN nearcountry.country_code;
437 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
440 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
442 RETURN nearcountry.country_code;
445 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
447 -- Natural earth data
448 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
450 RETURN nearcountry.country_code;
456 LANGUAGE plpgsql IMMUTABLE;
458 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
463 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
465 RETURN lower(nearcountry.country_default_language_code);
470 LANGUAGE plpgsql IMMUTABLE;
472 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
477 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
479 RETURN lower(nearcountry.country_default_language_codes);
484 LANGUAGE plpgsql IMMUTABLE;
486 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
491 FOR nearcountry IN select partition from country_name where country_code = in_country_code
493 RETURN nearcountry.partition;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
504 DELETE FROM location_area where place_id = OLD_place_id;
505 -- TODO:location_area
511 CREATE OR REPLACE FUNCTION add_location(
513 country_code varchar(2),
517 rank_address INTEGER,
532 IF rank_search > 25 THEN
533 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
536 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
538 x := deleteLocationArea(partition, place_id, rank_search);
541 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
544 centroid := ST_Centroid(geometry);
546 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
547 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
553 IF rank_address = 0 THEN
555 ELSEIF rank_search <= 14 THEN
557 ELSEIF rank_search <= 15 THEN
559 ELSEIF rank_search <= 16 THEN
561 ELSEIF rank_search <= 17 THEN
563 ELSEIF rank_search <= 21 THEN
565 ELSEIF rank_search = 25 THEN
569 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
571 secgeo := ST_Buffer(geometry, diameter);
572 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
582 -- find the parent road of the cut road parts
583 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
584 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
589 parent_place_id BIGINT;
590 address_street_word_ids INTEGER[];
596 addr_street = street;
599 IF addr_street is null and addr_place is null THEN
600 select nodes from planet_osm_ways where id = wayid INTO waynodes;
601 FOR location IN SELECT placex.street, placex.addr_place from placex
602 where osm_type = 'N' and osm_id = ANY(waynodes)
603 and (placex.street is not null or placex.addr_place is not null)
604 and indexed_status < 100
606 addr_street = location.street;
607 addr_place = location.addr_place;
611 IF addr_street IS NOT NULL THEN
612 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
613 IF address_street_word_ids IS NOT NULL THEN
614 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
615 parent_place_id := location.place_id;
620 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
621 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
622 IF address_street_word_ids IS NOT NULL THEN
623 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
624 parent_place_id := location.place_id;
629 IF parent_place_id is null THEN
630 FOR location IN SELECT place_id FROM placex
631 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
632 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
633 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
636 parent_place_id := location.place_id;
640 IF parent_place_id is null THEN
644 RETURN parent_place_id;
650 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
653 NEW.place_id := nextval('seq_place');
654 NEW.indexed_date := now();
656 IF NEW.indexed_status IS NULL THEN
657 IF NEW.interpolationtype NOT IN ('odd', 'even', 'all') THEN
658 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
662 NEW.indexed_status := 1; --STATUS_NEW
664 NEW.calculated_country_code := lower(get_country_code(NEW.linegeo));
666 NEW.partition := get_partition(NEW.calculated_country_code);
667 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
676 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
682 country_code VARCHAR(2);
683 default_language VARCHAR(10);
688 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
690 NEW.place_id := nextval('seq_place');
691 NEW.indexed_status := 1; --STATUS_NEW
693 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
695 NEW.partition := get_partition(NEW.calculated_country_code);
696 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
698 -- copy 'name' to or from the default language (if there is a default language)
699 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
700 default_language := get_country_language_code(NEW.calculated_country_code);
701 IF default_language IS NOT NULL THEN
702 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
703 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
704 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
705 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
710 IF NEW.admin_level > 15 THEN
711 NEW.admin_level := 15;
714 IF NEW.housenumber IS NOT NULL THEN
715 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
718 IF NEW.osm_type = 'X' THEN
719 -- E'X'ternal records should already be in the right format so do nothing
721 NEW.rank_search := 30;
722 NEW.rank_address := NEW.rank_search;
724 -- By doing in postgres we have the country available to us - currently only used for postcode
725 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
727 IF NEW.postcode IS NULL THEN
728 -- most likely just a part of a multipolygon postcode boundary, throw it away
732 NEW.name := hstore('ref', NEW.postcode);
734 IF NEW.calculated_country_code = 'gb' THEN
736 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
737 NEW.rank_search := 25;
738 NEW.rank_address := 5;
739 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
740 NEW.rank_search := 23;
741 NEW.rank_address := 5;
742 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
743 NEW.rank_search := 21;
744 NEW.rank_address := 5;
747 ELSEIF NEW.calculated_country_code = 'sg' THEN
749 IF NEW.postcode ~ '^([0-9]{6})$' THEN
750 NEW.rank_search := 25;
751 NEW.rank_address := 11;
754 ELSEIF NEW.calculated_country_code = 'de' THEN
756 IF NEW.postcode ~ '^([0-9]{5})$' THEN
757 NEW.rank_search := 21;
758 NEW.rank_address := 11;
762 -- Guess at the postcode format and coverage (!)
763 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
764 NEW.rank_search := 21;
765 NEW.rank_address := 11;
767 -- Does it look splitable into and area and local code?
768 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
770 IF postcode IS NOT NULL THEN
771 NEW.rank_search := 25;
772 NEW.rank_address := 11;
773 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
774 NEW.rank_search := 21;
775 NEW.rank_address := 11;
780 ELSEIF NEW.class = 'place' THEN
781 IF NEW.type in ('continent') THEN
782 NEW.rank_search := 2;
783 NEW.rank_address := NEW.rank_search;
784 NEW.calculated_country_code := NULL;
785 ELSEIF NEW.type in ('sea') THEN
786 NEW.rank_search := 2;
787 NEW.rank_address := 0;
788 NEW.calculated_country_code := NULL;
789 ELSEIF NEW.type in ('country') THEN
790 NEW.rank_search := 4;
791 NEW.rank_address := NEW.rank_search;
792 ELSEIF NEW.type in ('state') THEN
793 NEW.rank_search := 8;
794 NEW.rank_address := NEW.rank_search;
795 ELSEIF NEW.type in ('region') THEN
796 NEW.rank_search := 18; -- dropped from previous value of 10
797 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
798 ELSEIF NEW.type in ('county') THEN
799 NEW.rank_search := 12;
800 NEW.rank_address := NEW.rank_search;
801 ELSEIF NEW.type in ('city') THEN
802 NEW.rank_search := 16;
803 NEW.rank_address := NEW.rank_search;
804 ELSEIF NEW.type in ('island') THEN
805 NEW.rank_search := 17;
806 NEW.rank_address := 0;
807 ELSEIF NEW.type in ('town') THEN
808 NEW.rank_search := 18;
809 NEW.rank_address := 16;
810 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
811 NEW.rank_search := 19;
812 NEW.rank_address := 16;
813 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
814 NEW.rank_search := 20;
815 NEW.rank_address := NEW.rank_search;
816 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
817 NEW.rank_search := 20;
818 NEW.rank_address := 0;
819 -- Irish townlands, tagged as place=locality and locality=townland
820 IF (NEW.extratags -> 'locality') = 'townland' THEN
821 NEW.rank_address := 20;
823 ELSEIF NEW.type in ('neighbourhood') THEN
824 NEW.rank_search := 22;
825 NEW.rank_address := 22;
826 ELSEIF NEW.type in ('house','building') THEN
827 NEW.rank_search := 30;
828 NEW.rank_address := NEW.rank_search;
829 ELSEIF NEW.type in ('houses') THEN
830 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
831 NEW.rank_search := 28;
832 NEW.rank_address := 0;
835 ELSEIF NEW.class = 'boundary' THEN
836 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
837 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
840 NEW.rank_search := NEW.admin_level * 2;
841 IF NEW.type = 'administrative' THEN
842 NEW.rank_address := NEW.rank_search;
844 NEW.rank_address := 0;
846 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
847 NEW.rank_search := 22;
848 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
849 NEW.rank_address := NEW.rank_search;
851 NEW.rank_address := 0;
853 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
854 NEW.rank_search := 18;
855 NEW.rank_address := 0;
856 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
857 NEW.rank_search := 4;
858 NEW.rank_address := NEW.rank_search;
859 -- any feature more than 5 square miles is probably worth indexing
860 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
861 NEW.rank_search := 22;
862 NEW.rank_address := 0;
863 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
865 ELSEIF NEW.class = 'waterway' THEN
866 IF NEW.osm_type = 'R' THEN
867 NEW.rank_search := 16;
869 NEW.rank_search := 17;
871 NEW.rank_address := 0;
872 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
873 NEW.rank_search := 27;
874 NEW.rank_address := NEW.rank_search;
875 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
876 NEW.rank_search := 26;
877 NEW.rank_address := NEW.rank_search;
878 ELSEIF NEW.class = 'mountain_pass' THEN
879 NEW.rank_search := 20;
880 NEW.rank_address := 0;
885 IF NEW.rank_search > 30 THEN
886 NEW.rank_search := 30;
889 IF NEW.rank_address > 30 THEN
890 NEW.rank_address := 30;
893 IF (NEW.extratags -> 'capital') = 'yes' THEN
894 NEW.rank_search := NEW.rank_search - 1;
897 -- a country code make no sense below rank 4 (country)
898 IF NEW.rank_search < 4 THEN
899 NEW.calculated_country_code := NULL;
902 -- Block import below rank 22
903 -- IF NEW.rank_search > 22 THEN
907 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
909 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
911 IF NEW.rank_address > 0 THEN
912 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
913 -- Performance: We just can't handle re-indexing for country level changes
914 IF st_area(NEW.geometry) < 1 THEN
915 -- mark items within the geometry for re-indexing
916 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
918 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
919 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
920 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 addr_place is not null));
921 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
922 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 addr_place is not null));
925 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
927 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
928 IF NEW.type='postcode' THEN
930 ELSEIF NEW.rank_search < 16 THEN
932 ELSEIF NEW.rank_search < 18 THEN
934 ELSEIF NEW.rank_search < 20 THEN
936 ELSEIF NEW.rank_search = 21 THEN
938 ELSEIF NEW.rank_search < 24 THEN
940 ELSEIF NEW.rank_search < 26 THEN
941 diameter := 0.002; -- 100 to 200 meters
942 ELSEIF NEW.rank_search < 28 THEN
943 diameter := 0.001; -- 50 to 100 meters
946 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
947 IF NEW.rank_search >= 26 THEN
948 -- roads may cause reparenting for >27 rank places
949 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
950 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
951 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
952 ELSEIF NEW.rank_search >= 16 THEN
953 -- up to rank 16, street-less addresses may need reparenting
954 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 addr_place is not null);
956 -- for all other places the search terms may change as well
957 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);
964 -- add to tables for special search
965 -- Note: won't work on initial import because the classtype tables
966 -- do not yet exist. It won't hurt either.
967 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
968 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
970 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
971 USING NEW.place_id, ST_Centroid(NEW.geometry);
980 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
984 place_centroid GEOMETRY;
999 IF OLD.indexed_status = 100 THEN
1000 delete from location_property_osmline where place_id = OLD.place_id;
1004 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1008 -- do the reparenting: (finally here, because ALL places in placex,
1009 -- that are needed for reparenting, need to be up to date)
1010 -- (the osm interpolationline in location_property_osmline was marked for
1011 -- reparenting in placex_insert/placex_delete with index_status = 1 or 2 (1 inset, 2 delete)
1012 -- => index.c: sets index_status back to 0
1013 -- => triggers this function)
1014 place_centroid := ST_PointOnSurface(NEW.linegeo);
1015 -- marking descendants for reparenting is not needed, because there are
1016 -- actually no descendants for interpolation lines
1017 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1018 NEW.partition, place_centroid, NEW.linegeo);
1020 -- if we are just updating then our work is done
1021 IF OLD.indexed_status != 1 THEN
1025 -- otherwise split the line as necessary
1026 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1028 IF array_upper(waynodes, 1) IS NULL THEN
1032 linegeo := NEW.linegeo;
1033 startnumber := NULL;
1034 street := NEW.street;
1035 addr_place := NEW.addr_place;
1036 postcode := NEW.postcode;
1038 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1040 select * from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1041 and housenumber is not NULL limit 1 INTO nextnode;
1042 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1043 IF nextnode.osm_id IS NOT NULL THEN
1044 --RAISE NOTICE 'place_id is not null';
1045 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1046 -- Make sure that the point is actually on the line. That might
1047 -- be a bit paranoid but ensures that the algorithm still works
1048 -- should osm2pgsql attempt to repair geometries.
1049 splitline := split_line_on_node(linegeo, nextnode.geometry);
1050 sectiongeo := ST_GeometryN(splitline, 1);
1051 linegeo := ST_GeometryN(splitline, 2);
1053 sectiongeo = linegeo;
1055 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
1057 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1058 AND startnumber != endnumber
1059 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1061 IF (startnumber > endnumber) THEN
1062 housenum := endnumber;
1063 endnumber := startnumber;
1064 startnumber := housenum;
1065 sectiongeo := ST_Reverse(sectiongeo);
1068 IF NEW.startnumber IS NULL THEN
1069 NEW.startnumber := startnumber;
1070 NEW.endnumber := endnumber;
1071 NEW.linegeo := sectiongeo;
1072 NEW.street := coalesce(street, prevnode.street, nextnode.street);
1073 NEW.addr_place := coalesce(addr_place, prevnode.addr_place, nextnode.addr_place);
1074 NEW.postcode := coalesce(postcode, prevnode.postcode, nextnode.postcode);
1076 insert into location_property_osmline
1077 (linegeo, partition, osm_id, parent_place_id,
1078 startnumber, endnumber, interpolationtype,
1079 street, addr_place, postcode, calculated_country_code,
1080 geometry_sector, indexed_status)
1081 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1082 startnumber, endnumber, NEW.interpolationtype,
1083 coalesce(street, prevnode.street, nextnode.street),
1084 coalesce(addr_place, prevnode.addr_place, nextnode.addr_place),
1085 coalesce(postcode, prevnode.postcode, nextnode.postcode),
1086 NEW.calculated_country_code, NEW.geometry_sector, 0);
1090 -- early break if we are out of line string,
1091 -- might happen when a line string loops back on itself
1092 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1096 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
1097 prevnode := nextnode;
1108 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1113 place_centroid GEOMETRY;
1115 search_maxdistance FLOAT[];
1116 search_mindistance FLOAT[];
1117 address_havelevel BOOLEAN[];
1124 relation_members TEXT[];
1126 linkedplacex RECORD;
1127 search_diameter FLOAT;
1128 search_prevdiameter FLOAT;
1129 search_maxrank INTEGER;
1130 address_maxrank INTEGER;
1131 address_street_word_id INTEGER;
1132 address_street_word_ids INTEGER[];
1133 parent_place_id_rank BIGINT;
1138 location_rank_search INTEGER;
1139 location_distance FLOAT;
1140 location_parent GEOMETRY;
1141 location_isaddress BOOLEAN;
1142 location_keywords INTEGER[];
1144 default_language TEXT;
1145 name_vector INTEGER[];
1146 nameaddress_vector INTEGER[];
1148 linked_node_id BIGINT;
1153 IF OLD.indexed_status = 100 THEN
1154 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1155 delete from placex where place_id = OLD.place_id;
1159 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1163 -- ignore interpolated addresses
1164 IF NEW.class = 'place' and NEW.type = 'address' THEN
1168 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1170 --RAISE WARNING '%',NEW.place_id;
1171 --RAISE WARNING '%', NEW;
1173 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1174 -- Silently do nothing
1178 NEW.indexed_date = now();
1180 result := deleteSearchName(NEW.partition, NEW.place_id);
1181 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1182 result := deleteRoad(NEW.partition, NEW.place_id);
1183 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1184 UPDATE placex set linked_place_id = null, indexed_status = 2
1185 where linked_place_id = NEW.place_id;
1186 -- update not necessary for osmline, cause linked_place_id does not exist
1188 IF NEW.linked_place_id is not null THEN
1192 -- Speed up searches - just use the centroid of the feature
1193 -- cheaper but less acurate
1194 place_centroid := ST_PointOnSurface(NEW.geometry);
1195 NEW.centroid := null;
1197 -- recalculate country and partition
1198 IF NEW.rank_search = 4 THEN
1199 -- for countries, believe the mapped country code,
1200 -- so that we remain in the right partition if the boundaries
1202 NEW.partition := get_partition(lower(NEW.country_code));
1203 IF NEW.partition = 0 THEN
1204 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1205 NEW.partition := get_partition(NEW.calculated_country_code);
1207 NEW.calculated_country_code := lower(NEW.country_code);
1210 IF NEW.rank_search > 4 THEN
1211 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1212 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1214 NEW.calculated_country_code := NULL;
1216 NEW.partition := get_partition(NEW.calculated_country_code);
1219 -- waterway ways are linked when they are part of a relation and have the same class/type
1220 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1221 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1223 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1224 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1225 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1226 FOR linked_node_id IN SELECT place_id FROM placex
1227 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1228 and class = NEW.class and type = NEW.type
1229 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1231 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1238 -- Adding ourselves to the list simplifies address calculations later
1239 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1241 -- What level are we searching from
1242 search_maxrank := NEW.rank_search;
1244 -- Thought this wasn't needed but when we add new languages to the country_name table
1245 -- we need to update the existing names
1246 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1247 default_language := get_country_language_code(NEW.calculated_country_code);
1248 IF default_language IS NOT NULL THEN
1249 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1250 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1251 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1252 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1257 -- Initialise the name vector using our name
1258 name_vector := make_keywords(NEW.name);
1259 nameaddress_vector := '{}'::int[];
1262 address_havelevel[i] := false;
1265 NEW.importance := null;
1266 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1267 IF NEW.importance IS NULL THEN
1268 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;
1271 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1273 -- ---------------------------------------------------------------------------
1274 -- For low level elements we inherit from our parent road
1275 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1277 --RAISE WARNING 'finding street for %', NEW;
1279 -- We won't get a better centroid, besides these places are too small to care
1280 NEW.centroid := place_centroid;
1282 NEW.parent_place_id := null;
1284 -- if we have a POI and there is no address information,
1285 -- see if we can get it from a surrounding building
1286 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1287 AND NEW.housenumber IS NULL THEN
1288 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1289 and (housenumber is not null or street is not null or addr_place is not null)
1290 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1293 NEW.housenumber := location.housenumber;
1294 NEW.street := location.street;
1295 NEW.addr_place := location.addr_place;
1299 -- We have to find our parent road.
1300 -- Copy data from linked items (points on ways, addr:street links, relations)
1302 -- Is this object part of a relation?
1303 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1305 -- At the moment we only process one type of relation - associatedStreet
1306 IF relation.tags @> ARRAY['associatedStreet'] THEN
1307 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1308 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1309 --RAISE WARNING 'node in relation %',relation;
1310 SELECT place_id from placex where osm_type = 'W'
1311 and osm_id = substring(relation.members[i],2,200)::bigint
1312 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1319 -- Note that addr:street links can only be indexed once the street itself is indexed
1320 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1321 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1322 IF address_street_word_ids IS NOT NULL THEN
1323 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1324 NEW.parent_place_id := location.place_id;
1329 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1330 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1331 IF address_street_word_ids IS NOT NULL THEN
1332 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1333 NEW.parent_place_id := location.place_id;
1338 -- Is this node part of an interpolation?
1339 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1341 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1342 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1345 NEW.parent_place_id := location.parent_place_id;
1349 -- Is this node part of a way?
1350 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1352 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w
1353 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)
1356 -- Way IS a road then we are on it - that must be our road
1357 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1358 --RAISE WARNING 'node in way that is a street %',location;
1359 NEW.parent_place_id := location.place_id;
1362 -- If the way mentions a street or place address, try that for parenting.
1363 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1364 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1365 IF address_street_word_ids IS NOT NULL THEN
1366 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1367 NEW.parent_place_id := linkedplacex.place_id;
1372 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1373 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1374 IF address_street_word_ids IS NOT NULL THEN
1375 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1376 NEW.parent_place_id := linkedplacex.place_id;
1381 -- Is the WAY part of a relation
1382 IF NEW.parent_place_id IS NULL THEN
1383 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1385 -- At the moment we only process one type of relation - associatedStreet
1386 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1387 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1388 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1389 --RAISE WARNING 'node in way that is in a relation %',relation;
1390 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1391 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1402 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1403 -- Still nothing, just use the nearest road
1404 IF NEW.parent_place_id IS NULL THEN
1405 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1406 NEW.parent_place_id := location.place_id;
1411 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1413 -- If we didn't find any road fallback to standard method
1414 IF NEW.parent_place_id IS NOT NULL THEN
1416 -- Get the details of the parent road
1417 select * from search_name where place_id = NEW.parent_place_id INTO location;
1418 NEW.calculated_country_code := location.country_code;
1420 -- Merge the postcode into the parent's address if necessary XXXX
1421 IF NEW.postcode IS NOT NULL THEN
1422 isin_tokens := '{}'::int[];
1423 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1424 IF address_street_word_id is not null
1425 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1426 isin_tokens := isin_tokens || address_street_word_id;
1428 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1429 IF address_street_word_id is not null
1430 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1431 isin_tokens := isin_tokens || address_street_word_id;
1433 IF isin_tokens != '{}'::int[] THEN
1435 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1436 WHERE place_id = NEW.parent_place_id;
1440 --RAISE WARNING '%', NEW.name;
1441 -- If there is no name it isn't searchable, don't bother to create a search record
1442 IF NEW.name is NULL THEN
1446 -- Merge address from parent
1447 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1448 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1450 -- Performance, it would be more acurate to do all the rest of the import
1451 -- process but it takes too long
1452 -- Just be happy with inheriting from parent road only
1454 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1455 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1458 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1465 -- RAISE WARNING ' INDEXING Started:';
1466 -- RAISE WARNING ' INDEXING: %',NEW;
1468 -- ---------------------------------------------------------------------------
1471 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1473 -- see if we have any special relation members
1474 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1476 -- RAISE WARNING 'get_osm_rel_members, label';
1477 IF relation_members IS NOT NULL THEN
1478 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1480 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1481 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1483 -- If we don't already have one use this as the centre point of the geometry
1484 IF NEW.centroid IS NULL THEN
1485 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1488 -- merge in the label name, re-init word vector
1489 IF NOT linkedPlacex.name IS NULL THEN
1490 NEW.name := linkedPlacex.name || NEW.name;
1491 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1494 -- merge in extra tags
1495 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1497 -- mark the linked place (excludes from search results)
1498 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1500 -- keep a note of the node id in case we need it for wikipedia in a bit
1501 linked_node_id := linkedPlacex.osm_id;
1506 IF NEW.centroid IS NULL THEN
1508 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1510 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1511 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1513 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1514 -- But that can be fixed by explicitly setting the label in the data
1515 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1516 AND NEW.rank_address = linkedPlacex.rank_address THEN
1518 -- If we don't already have one use this as the centre point of the geometry
1519 IF NEW.centroid IS NULL THEN
1520 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1523 -- merge in the name, re-init word vector
1524 IF NOT linkedPlacex.name IS NULL THEN
1525 NEW.name := linkedPlacex.name || NEW.name;
1526 name_vector := make_keywords(NEW.name);
1529 -- merge in extra tags
1530 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1532 -- mark the linked place (excludes from search results)
1533 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1535 -- keep a note of the node id in case we need it for wikipedia in a bit
1536 linked_node_id := linkedPlacex.osm_id;
1548 -- Name searches can be done for ways as well as relations
1549 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1551 -- not found one yet? how about doing a name search
1552 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1554 FOR linkedPlacex IN select placex.* from placex WHERE
1555 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1556 AND placex.rank_address = NEW.rank_address
1557 AND placex.place_id != NEW.place_id
1558 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1559 AND st_covers(NEW.geometry, placex.geometry)
1562 -- If we don't already have one use this as the centre point of the geometry
1563 IF NEW.centroid IS NULL THEN
1564 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1567 -- merge in the name, re-init word vector
1568 NEW.name := linkedPlacex.name || NEW.name;
1569 name_vector := make_keywords(NEW.name);
1571 -- merge in extra tags
1572 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1574 -- mark the linked place (excludes from search results)
1575 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1577 -- keep a note of the node id in case we need it for wikipedia in a bit
1578 linked_node_id := linkedPlacex.osm_id;
1582 IF NEW.centroid IS NOT NULL THEN
1583 place_centroid := NEW.centroid;
1584 -- Place might have had only a name tag before but has now received translations
1585 -- from the linked place. Make sure a name tag for the default language exists in
1587 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1588 default_language := get_country_language_code(NEW.calculated_country_code);
1589 IF default_language IS NOT NULL THEN
1590 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1591 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1592 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1593 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1599 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1600 IF NEW.importance is null THEN
1601 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1603 -- Still null? how about looking it up by the node id
1604 IF NEW.importance IS NULL THEN
1605 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;
1610 -- make sure all names are in the word table
1611 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1612 perform create_country(NEW.name, lower(NEW.country_code));
1615 NEW.parent_place_id = 0;
1616 parent_place_id_rank = 0;
1619 -- convert isin to array of tokenids
1620 isin_tokens := '{}'::int[];
1621 IF NEW.isin IS NOT NULL THEN
1622 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1623 IF array_upper(isin, 1) IS NOT NULL THEN
1624 FOR i IN 1..array_upper(isin, 1) LOOP
1625 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1626 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1627 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1628 isin_tokens := isin_tokens || address_street_word_id;
1631 -- merge word into address vector
1632 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1633 IF address_street_word_id IS NOT NULL THEN
1634 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1639 IF NEW.postcode IS NOT NULL THEN
1640 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1641 IF array_upper(isin, 1) IS NOT NULL THEN
1642 FOR i IN 1..array_upper(isin, 1) LOOP
1643 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1644 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1645 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1646 isin_tokens := isin_tokens || address_street_word_id;
1649 -- merge into address vector
1650 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1651 IF address_street_word_id IS NOT NULL THEN
1652 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1658 -- %NOTIGERDATA% IF 0 THEN
1659 -- for the USA we have an additional address table. Merge in zip codes from there too
1660 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1661 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1662 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1663 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1664 isin_tokens := isin_tokens || address_street_word_id;
1666 -- also merge in the single word version
1667 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1668 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1671 -- %NOTIGERDATA% END IF;
1673 -- RAISE WARNING 'ISIN: %', isin_tokens;
1675 -- Process area matches
1676 location_rank_search := 0;
1677 location_distance := 0;
1678 location_parent := NULL;
1679 -- added ourself as address already
1680 address_havelevel[NEW.rank_address] := true;
1681 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1682 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1684 --RAISE WARNING ' AREA: %',location;
1686 IF location.rank_address != location_rank_search THEN
1687 location_rank_search := location.rank_address;
1688 IF location.isguess THEN
1689 location_distance := location.distance * 1.5;
1691 IF location.rank_address <= 12 THEN
1692 -- for county and above, if we have an area consider that exact
1693 -- (It would be nice to relax the constraint for places close to
1694 -- the boundary but we'd need the exact geometry for that. Too
1696 location_distance = 0;
1698 -- Below county level remain slightly fuzzy.
1699 location_distance := location.distance * 0.5;
1703 CONTINUE WHEN location.keywords <@ location_keywords;
1706 IF location.distance < location_distance OR NOT location.isguess THEN
1707 location_keywords := location.keywords;
1709 location_isaddress := NOT address_havelevel[location.rank_address];
1710 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1711 location_isaddress := ST_Contains(location_parent,location.centroid);
1714 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1715 -- Add it to the list of search terms
1716 IF location.rank_search > 4 THEN
1717 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1719 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1721 IF location_isaddress THEN
1723 address_havelevel[location.rank_address] := true;
1724 IF NOT location.isguess THEN
1725 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1728 IF location.rank_address > parent_place_id_rank THEN
1729 NEW.parent_place_id = location.place_id;
1730 parent_place_id_rank = location.rank_address;
1735 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1741 -- try using the isin value to find parent places
1742 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1743 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1744 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1745 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1747 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1749 --RAISE WARNING ' ISIN: %',location;
1751 IF location.rank_search > 4 THEN
1752 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1753 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1754 address_havelevel[location.rank_address] := true;
1756 IF location.rank_address > parent_place_id_rank THEN
1757 NEW.parent_place_id = location.place_id;
1758 parent_place_id_rank = location.rank_address;
1768 -- for long ways we should add search terms for the entire length
1769 IF st_length(NEW.geometry) > 0.05 THEN
1771 location_rank_search := 0;
1772 location_distance := 0;
1774 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1776 IF location.rank_address != location_rank_search THEN
1777 location_rank_search := location.rank_address;
1778 location_distance := location.distance * 1.5;
1781 IF location.rank_search > 4 AND location.distance < location_distance THEN
1783 -- Add it to the list of search terms
1784 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1785 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1793 -- if we have a name add this to the name search table
1794 IF NEW.name IS NOT NULL THEN
1796 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1797 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1800 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1801 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1804 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1808 -- If we've not managed to pick up a better one - default centroid
1809 IF NEW.centroid IS NULL THEN
1810 NEW.centroid := place_centroid;
1818 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1824 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1826 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1827 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1828 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1829 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1831 IF OLD.rank_address < 30 THEN
1833 -- mark everything linked to this place for re-indexing
1834 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1835 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1836 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1838 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1839 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1841 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1842 b := deleteRoad(OLD.partition, OLD.place_id);
1844 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1845 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1846 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1847 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1848 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1852 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1854 IF OLD.rank_address < 26 THEN
1855 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1858 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1860 IF OLD.name is not null THEN
1861 b := deleteSearchName(OLD.partition, OLD.place_id);
1864 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1866 DELETE FROM place_addressline where place_id = OLD.place_id;
1868 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1870 -- remove from tables for special search
1871 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1872 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1874 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1877 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1885 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1891 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1893 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1894 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1895 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;
1897 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1903 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;
1905 -- interpolations are special
1906 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1907 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1916 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1921 existingplacex RECORD;
1922 existingline RECORD;
1923 existinggeometry GEOMETRY;
1924 existingplace_id BIGINT;
1929 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1930 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1931 -- filter wrong tupels
1932 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
1933 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1934 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1935 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1939 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
1940 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1941 -- Have we already done this place?
1942 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;
1944 -- Get the existing place_id
1945 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1947 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1948 IF existing.osm_type IS NULL THEN
1949 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1952 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1953 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1955 -- 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)
1956 IF existingline.osm_id IS NOT NULL THEN
1957 delete from location_property_osmline where osm_id = NEW.osm_id;
1960 -- for interpolations invalidate all nodes on the line
1961 update placex p set indexed_status = 2
1962 from planet_osm_ways w
1963 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
1966 INSERT INTO location_property_osmline
1967 (osm_id, interpolationtype, street,
1968 addr_place, postcode, calculated_country_code, linegeo)
1969 VALUES (NEW.osm_id, NEW.housenumber, NEW.street,
1970 NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry);
1973 IF existing.osm_type IS NULL THEN
1977 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1978 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1979 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
1980 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1981 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1982 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1983 OR existing.geometry::text != NEW.geometry::text
1988 housenumber = NEW.housenumber,
1989 street = NEW.street,
1990 addr_place = NEW.addr_place,
1992 postcode = NEW.postcode,
1993 country_code = NEW.country_code,
1994 extratags = NEW.extratags,
1995 admin_level = NEW.admin_level,
1996 geometry = NEW.geometry
1997 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2002 ELSE -- insert to placex
2004 -- Patch in additional country names
2005 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2006 SELECT name FROM country_name WHERE country_code = lower(NEW.country_code) INTO existing;
2007 IF existing.name IS NOT NULL THEN
2008 NEW.name = existing.name || NEW.name;
2012 -- Have we already done this place?
2013 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;
2015 -- Get the existing place_id
2016 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;
2018 -- Handle a place changing type by removing the old data
2019 -- My generated 'place' types are causing havok because they overlap with real keys
2020 -- TODO: move them to their own special purpose key/class to avoid collisions
2021 IF existing.osm_type IS NULL THEN
2022 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2025 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2026 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2029 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2030 AND st_area(existing.geometry) > 0.02
2031 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2032 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2034 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2035 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2039 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2040 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2042 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2043 IF existingplacex.osm_type IS NULL OR
2044 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2047 IF existingplacex.osm_type IS NOT NULL THEN
2048 -- sanity check: ignore admin_level changes on places with too many active children
2049 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2050 --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;
2051 --LIMIT INDEXING: IF i > 100000 THEN
2052 --LIMIT INDEXING: RETURN null;
2053 --LIMIT INDEXING: END IF;
2056 IF existing.osm_type IS NOT NULL THEN
2057 -- pathological case caused by the triggerless copy into place during initial import
2058 -- force delete even for large areas, it will be reinserted later
2059 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;
2060 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2063 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2064 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2065 street, addr_place, isin, postcode, country_code, extratags, geometry)
2066 values (NEW.osm_type
2082 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2087 -- Various ways to do the update
2089 -- Debug, what's changed?
2091 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2092 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2094 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2095 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2097 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2098 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2100 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2101 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2103 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2104 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2106 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2107 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2109 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2110 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2114 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2115 IF existing.geometry::text != NEW.geometry::text
2116 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2117 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2120 -- Get the version of the geometry actually used (in placex table)
2121 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;
2123 -- Performance limit
2124 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2126 -- 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
2127 update placex set indexed_status = 2 where indexed_status = 0 and
2128 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2129 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2130 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2132 update placex set indexed_status = 2 where indexed_status = 0 and
2133 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2134 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2135 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2142 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2143 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2144 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2145 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2146 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2147 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2148 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2149 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2150 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2151 OR existing.geometry::text != NEW.geometry::text
2156 housenumber = NEW.housenumber,
2157 street = NEW.street,
2158 addr_place = NEW.addr_place,
2160 postcode = NEW.postcode,
2161 country_code = NEW.country_code,
2162 extratags = NEW.extratags,
2163 admin_level = NEW.admin_level,
2164 geometry = NEW.geometry
2165 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2168 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2169 IF NEW.postcode IS NULL THEN
2170 -- postcode was deleted, no longer retain in placex
2171 DELETE FROM placex where place_id = existingplacex.place_id;
2175 NEW.name := hstore('ref', NEW.postcode);
2180 housenumber = NEW.housenumber,
2181 street = NEW.street,
2182 addr_place = NEW.addr_place,
2184 postcode = NEW.postcode,
2185 country_code = NEW.country_code,
2186 parent_place_id = null,
2187 extratags = NEW.extratags,
2188 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2190 geometry = NEW.geometry
2191 where place_id = existingplacex.place_id;
2193 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2194 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2195 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2196 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2197 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);
2202 -- Abort the add (we modified the existing place instead)
2207 $$ LANGUAGE plpgsql;
2210 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2215 IF name is null THEN
2219 FOR j IN 1..array_upper(languagepref,1) LOOP
2220 IF name ? languagepref[j] THEN
2221 result := trim(name->languagepref[j]);
2222 IF result != '' THEN
2228 -- anything will do as a fallback - just take the first name type thing there is
2229 RETURN trim((avals(name))[1]);
2232 LANGUAGE plpgsql IMMUTABLE;
2235 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2246 search := ARRAY['ref'];
2249 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2252 select rank_address,name,distance,length(name::text) as namelength
2253 from place_addressline join placex on (address_place_id = placex.place_id)
2254 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2255 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2257 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2258 FOR j IN 1..array_upper(search, 1) LOOP
2259 FOR k IN 1..array_upper(location.name, 1) LOOP
2260 IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
2261 result[(100 - location.rank_address)] := trim(location.name[k].value);
2262 found := location.rank_address;
2269 RETURN array_to_string(result,', ');
2274 --housenumber only needed for tiger data
2275 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2287 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2288 currresult := trim(get_name_by_language(location.name, languagepref));
2289 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2290 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2291 prevresult := currresult;
2295 RETURN array_to_string(result,', ');
2300 DROP TYPE IF EXISTS addressline CASCADE;
2301 create type addressline as (
2308 admin_level INTEGER,
2311 rank_address INTEGER,
2315 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2318 for_place_id BIGINT;
2323 countrylocation RECORD;
2324 searchcountrycode varchar(2);
2325 searchhousenumber TEXT;
2326 searchhousename HSTORE;
2327 searchrankaddress INTEGER;
2328 searchpostcode TEXT;
2334 -- first query osmline (interpolation lines)
2335 select parent_place_id, calculated_country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2336 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2337 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2338 IF for_place_id IS NOT NULL THEN
2339 searchhousenumber = in_housenumber::text;
2342 --then query tiger data
2343 -- %NOTIGERDATA% IF 0 THEN
2344 IF for_place_id IS NULL THEN
2345 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2346 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2347 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2348 IF for_place_id IS NOT NULL THEN
2349 searchhousenumber = in_housenumber::text;
2352 -- %NOTIGERDATA% END IF;
2354 -- %NOAUXDATA% IF 0 THEN
2355 IF for_place_id IS NULL THEN
2356 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2357 WHERE place_id = in_place_id
2358 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2360 -- %NOAUXDATA% END IF;
2362 IF for_place_id IS NULL THEN
2363 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2364 WHERE place_id = in_place_id and rank_search > 27
2365 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2368 IF for_place_id IS NULL THEN
2369 select coalesce(linked_place_id, place_id), calculated_country_code,
2370 housenumber, rank_search, postcode, null
2371 from placex where place_id = in_place_id
2372 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2375 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2378 hadcountry := false;
2380 select placex.place_id, osm_type, osm_id,
2381 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2382 class, type, admin_level, true as fromarea, true as isaddress,
2383 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2384 0 as distance, calculated_country_code, postcode
2386 where place_id = for_place_id
2388 --RAISE WARNING '%',location;
2389 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2390 searchcountrycode := location.calculated_country_code;
2392 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2393 location.isaddress := FALSE;
2395 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2396 searchpostcode := location.postcode;
2398 IF location.rank_address = 4 AND location.isaddress THEN
2401 IF location.rank_address < 4 AND NOT hadcountry THEN
2402 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2403 IF countryname IS NOT NULL THEN
2404 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2405 RETURN NEXT countrylocation;
2408 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2409 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2410 location.distance)::addressline;
2411 RETURN NEXT countrylocation;
2412 found := location.rank_address;
2416 select placex.place_id, osm_type, osm_id,
2417 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2418 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2419 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2420 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
2421 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,
2422 distance,calculated_country_code,postcode
2423 from place_addressline join placex on (address_place_id = placex.place_id)
2424 where place_addressline.place_id = for_place_id
2425 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2426 and address_place_id != for_place_id
2427 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2428 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2430 --RAISE WARNING '%',location;
2431 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2432 searchcountrycode := location.calculated_country_code;
2434 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2435 location.isaddress := FALSE;
2437 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2438 searchpostcode := location.postcode;
2440 IF location.rank_address = 4 AND location.isaddress THEN
2443 IF location.rank_address < 4 AND NOT hadcountry THEN
2444 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2445 IF countryname IS NOT NULL THEN
2446 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2447 RETURN NEXT countrylocation;
2450 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2451 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2452 location.distance)::addressline;
2453 RETURN NEXT countrylocation;
2454 found := location.rank_address;
2458 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2459 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2460 IF countryname IS NOT NULL THEN
2461 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2462 RETURN NEXT location;
2466 IF searchcountrycode IS NOT NULL THEN
2467 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2468 RETURN NEXT location;
2471 IF searchhousename IS NOT NULL THEN
2472 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2473 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2474 RETURN NEXT location;
2477 IF searchhousenumber IS NOT NULL THEN
2478 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2479 RETURN NEXT location;
2482 IF searchpostcode IS NOT NULL THEN
2483 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2484 RETURN NEXT location;
2493 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2496 numfeatures integer;
2500 housenumber = place.housenumber,
2501 street = place.street,
2502 addr_place = place.addr_place,
2504 postcode = place.postcode,
2505 country_code = place.country_code,
2506 parent_place_id = null
2508 where placex.place_id = search_place_id
2509 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2510 and place.class = placex.class and place.type = placex.type;
2511 update placex set indexed_status = 2 where place_id = search_place_id;
2512 update placex set indexed_status = 0 where place_id = search_place_id;
2518 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2524 ELSEIF rank < 4 THEN
2526 ELSEIF rank < 8 THEN
2528 ELSEIF rank < 12 THEN
2530 ELSEIF rank < 16 THEN
2532 ELSEIF rank = 16 THEN
2534 ELSEIF rank = 17 THEN
2535 RETURN 'Town / Island';
2536 ELSEIF rank = 18 THEN
2537 RETURN 'Village / Hamlet';
2538 ELSEIF rank = 20 THEN
2540 ELSEIF rank = 21 THEN
2541 RETURN 'Postcode Area';
2542 ELSEIF rank = 22 THEN
2543 RETURN 'Croft / Farm / Locality / Islet';
2544 ELSEIF rank = 23 THEN
2545 RETURN 'Postcode Area';
2546 ELSEIF rank = 25 THEN
2547 RETURN 'Postcode Point';
2548 ELSEIF rank = 26 THEN
2549 RETURN 'Street / Major Landmark';
2550 ELSEIF rank = 27 THEN
2551 RETURN 'Minory Street / Path';
2552 ELSEIF rank = 28 THEN
2553 RETURN 'House / Building';
2555 RETURN 'Other: '||rank;
2562 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2568 ELSEIF rank < 2 THEN
2570 ELSEIF rank < 4 THEN
2572 ELSEIF rank = 5 THEN
2574 ELSEIF rank < 8 THEN
2576 ELSEIF rank < 12 THEN
2578 ELSEIF rank < 16 THEN
2580 ELSEIF rank = 16 THEN
2582 ELSEIF rank = 17 THEN
2583 RETURN 'Town / Village / Hamlet';
2584 ELSEIF rank = 20 THEN
2586 ELSEIF rank = 21 THEN
2587 RETURN 'Postcode Area';
2588 ELSEIF rank = 22 THEN
2589 RETURN 'Croft / Farm / Locality / Islet';
2590 ELSEIF rank = 23 THEN
2591 RETURN 'Postcode Area';
2592 ELSEIF rank = 25 THEN
2593 RETURN 'Postcode Point';
2594 ELSEIF rank = 26 THEN
2595 RETURN 'Street / Major Landmark';
2596 ELSEIF rank = 27 THEN
2597 RETURN 'Minory Street / Path';
2598 ELSEIF rank = 28 THEN
2599 RETURN 'House / Building';
2601 RETURN 'Other: '||rank;
2608 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2609 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2614 place_centroid GEOMETRY;
2615 out_partition INTEGER;
2616 out_parent_place_id BIGINT;
2618 address_street_word_id INTEGER;
2623 place_centroid := ST_Centroid(pointgeo);
2624 out_partition := get_partition(in_countrycode);
2625 out_parent_place_id := null;
2627 address_street_word_id := get_name_id(make_standard_name(in_street));
2628 IF address_street_word_id IS NOT NULL THEN
2629 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2630 out_parent_place_id := location.place_id;
2634 IF out_parent_place_id IS NULL THEN
2635 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2636 out_parent_place_id := location.place_id;
2640 out_postcode := in_postcode;
2641 IF out_postcode IS NULL THEN
2642 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2644 IF out_postcode IS NULL THEN
2645 out_postcode := getNearestPostcode(out_partition, place_centroid);
2649 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2650 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2651 newpoints := newpoints + 1;
2658 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2665 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2666 IF members[i+1] = member THEN
2667 result := result || members[i];
2676 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2682 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2683 IF members[i+1] = ANY(memberLabels) THEN
2684 RETURN NEXT members[i];
2693 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2694 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2696 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2697 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
2698 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2699 ), '') AS bytea), 'UTF8');
2701 LANGUAGE SQL IMMUTABLE STRICT;
2703 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2707 RETURN decode_url_part(p);
2709 WHEN others THEN return null;
2712 LANGUAGE plpgsql IMMUTABLE;
2714 DROP TYPE wikipedia_article_match CASCADE;
2715 create type wikipedia_article_match as (
2721 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2727 wiki_article_title TEXT;
2728 wiki_article_language TEXT;
2729 result wikipedia_article_match;
2731 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'];
2733 WHILE langs[i] IS NOT NULL LOOP
2734 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2735 IF wiki_article is not null THEN
2736 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2737 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2738 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2739 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2740 wiki_article := replace(wiki_article,' ','_');
2741 IF strpos(wiki_article, ':') IN (3,4) THEN
2742 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2743 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2745 wiki_article_title := trim(wiki_article);
2746 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;
2749 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2750 from wikipedia_article
2751 where language = wiki_article_language and
2752 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2754 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2755 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2756 where wikipedia_redirect.language = wiki_article_language and
2757 (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'\\',''))
2758 order by importance desc limit 1 INTO result;
2760 IF result.language is not null THEN
2771 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2772 RETURNS SETOF GEOMETRY
2786 remainingdepth INTEGER;
2791 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2793 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2794 RETURN NEXT geometry;
2798 remainingdepth := maxdepth - 1;
2799 area := ST_AREA(geometry);
2800 IF remainingdepth < 1 OR area < maxarea THEN
2801 RETURN NEXT geometry;
2805 xmin := st_xmin(geometry);
2806 xmax := st_xmax(geometry);
2807 ymin := st_ymin(geometry);
2808 ymax := st_ymax(geometry);
2809 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2811 -- if the geometry completely covers the box don't bother to slice any more
2812 IF ST_AREA(secbox) = area THEN
2813 RETURN NEXT geometry;
2817 xmid := (xmin+xmax)/2;
2818 ymid := (ymin+ymax)/2;
2821 FOR seg IN 1..4 LOOP
2824 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2827 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2830 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2833 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2836 IF st_intersects(geometry, secbox) THEN
2837 secgeo := st_intersection(geometry, secbox);
2838 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2839 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2840 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2842 RETURN NEXT geo.geom;
2854 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2855 RETURNS SETOF GEOMETRY
2860 -- 10000000000 is ~~ 1x1 degree
2861 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2862 RETURN NEXT geo.geom;
2870 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2874 osmtype character(1);
2878 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2879 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2880 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2881 -- force delete from place/placex by making it a very small geometry
2882 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;
2883 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2890 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2898 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2899 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2900 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2901 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2902 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2903 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2904 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 addr_place is not null));
2905 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2906 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 addr_place is not null));
2912 ELSEIF rank < 18 THEN
2914 ELSEIF rank < 20 THEN
2916 ELSEIF rank = 21 THEN
2918 ELSEIF rank < 24 THEN
2920 ELSEIF rank < 26 THEN
2921 diameter := 0.002; -- 100 to 200 meters
2922 ELSEIF rank < 28 THEN
2923 diameter := 0.001; -- 50 to 100 meters
2925 IF diameter > 0 THEN
2927 -- roads may cause reparenting for >27 rank places
2928 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2929 ELSEIF rank >= 16 THEN
2930 -- up to rank 16, street-less addresses may need reparenting
2931 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 addr_place is not null);
2933 -- for all other places the search terms may change as well
2934 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);