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.address from placex
602 where osm_type = 'N' and osm_id = ANY(waynodes)
603 and placex.address is not null
604 and (placex.address ? 'street' or placex.address ? 'place')
605 and indexed_status < 100
607 addr_street = location.address->'street';
608 addr_place = location.address->'place';
612 IF addr_street IS NOT NULL THEN
613 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
614 IF address_street_word_ids IS NOT NULL THEN
615 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
616 parent_place_id := location.place_id;
621 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
622 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
623 IF address_street_word_ids IS NOT NULL THEN
624 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
625 parent_place_id := location.place_id;
630 IF parent_place_id is null THEN
631 FOR location IN SELECT place_id FROM placex
632 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
633 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
635 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
637 parent_place_id := location.place_id;
641 IF parent_place_id is null THEN
645 RETURN parent_place_id;
651 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
654 NEW.place_id := nextval('seq_place');
655 NEW.indexed_date := now();
657 IF NEW.indexed_status IS NULL THEN
658 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
659 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
660 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
664 NEW.indexed_status := 1; --STATUS_NEW
665 NEW.country_code := lower(get_country_code(NEW.linegeo));
667 NEW.partition := get_partition(NEW.country_code);
668 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
677 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
683 country_code VARCHAR(2);
684 default_language VARCHAR(10);
689 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
691 NEW.place_id := nextval('seq_place');
692 NEW.indexed_status := 1; --STATUS_NEW
694 NEW.country_code := lower(get_country_code(NEW.geometry));
696 NEW.partition := get_partition(NEW.country_code);
697 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
699 -- copy 'name' to or from the default language (if there is a default language)
700 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
701 default_language := get_country_language_code(NEW.country_code);
702 IF default_language IS NOT NULL THEN
703 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
704 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
705 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
706 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
711 IF NEW.osm_type = 'X' THEN
712 -- E'X'ternal records should already be in the right format so do nothing
714 NEW.rank_search := 30;
715 NEW.rank_address := NEW.rank_search;
717 -- By doing in postgres we have the country available to us - currently only used for postcode
718 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
720 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
721 -- most likely just a part of a multipolygon postcode boundary, throw it away
725 NEW.postcode := NEW.address->'postcode';
726 NEW.name := hstore('ref', NEW.postcode);
728 IF NEW.country_code = 'gb' THEN
730 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
731 NEW.rank_search := 25;
732 NEW.rank_address := 5;
733 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
734 NEW.rank_search := 23;
735 NEW.rank_address := 5;
736 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
737 NEW.rank_search := 21;
738 NEW.rank_address := 5;
741 ELSEIF NEW.country_code = 'sg' THEN
743 IF NEW.postcode ~ '^([0-9]{6})$' THEN
744 NEW.rank_search := 25;
745 NEW.rank_address := 11;
748 ELSEIF NEW.country_code = 'de' THEN
750 IF NEW.postcode ~ '^([0-9]{5})$' THEN
751 NEW.rank_search := 21;
752 NEW.rank_address := 11;
756 -- Guess at the postcode format and coverage (!)
757 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
758 NEW.rank_search := 21;
759 NEW.rank_address := 11;
761 -- Does it look splitable into and area and local code?
762 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
764 IF postcode IS NOT NULL THEN
765 NEW.rank_search := 25;
766 NEW.rank_address := 11;
767 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
768 NEW.rank_search := 21;
769 NEW.rank_address := 11;
774 ELSEIF NEW.class = 'place' THEN
775 IF NEW.type in ('continent') THEN
776 NEW.rank_search := 2;
777 NEW.rank_address := NEW.rank_search;
778 NEW.country_code := NULL;
779 ELSEIF NEW.type in ('sea') THEN
780 NEW.rank_search := 2;
781 NEW.rank_address := 0;
782 NEW.country_code := NULL;
783 ELSEIF NEW.type in ('country') THEN
784 NEW.rank_search := 4;
785 NEW.rank_address := NEW.rank_search;
786 ELSEIF NEW.type in ('state') THEN
787 NEW.rank_search := 8;
788 NEW.rank_address := NEW.rank_search;
789 ELSEIF NEW.type in ('region') THEN
790 NEW.rank_search := 18; -- dropped from previous value of 10
791 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
792 ELSEIF NEW.type in ('county') THEN
793 NEW.rank_search := 12;
794 NEW.rank_address := NEW.rank_search;
795 ELSEIF NEW.type in ('city') THEN
796 NEW.rank_search := 16;
797 NEW.rank_address := NEW.rank_search;
798 ELSEIF NEW.type in ('island') THEN
799 NEW.rank_search := 17;
800 NEW.rank_address := 0;
801 ELSEIF NEW.type in ('town') THEN
802 NEW.rank_search := 18;
803 NEW.rank_address := 16;
804 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
805 NEW.rank_search := 19;
806 NEW.rank_address := 16;
807 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
808 NEW.rank_search := 20;
809 NEW.rank_address := NEW.rank_search;
810 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
811 NEW.rank_search := 20;
812 NEW.rank_address := 0;
813 -- Irish townlands, tagged as place=locality and locality=townland
814 IF (NEW.extratags -> 'locality') = 'townland' THEN
815 NEW.rank_address := 20;
817 ELSEIF NEW.type in ('neighbourhood') THEN
818 NEW.rank_search := 22;
819 NEW.rank_address := 22;
820 ELSEIF NEW.type in ('house','building') THEN
821 NEW.rank_search := 30;
822 NEW.rank_address := NEW.rank_search;
823 ELSEIF NEW.type in ('houses') THEN
824 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
825 NEW.rank_search := 28;
826 NEW.rank_address := 0;
829 ELSEIF NEW.class = 'boundary' THEN
830 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
831 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
834 NEW.rank_search := NEW.admin_level * 2;
835 IF NEW.type = 'administrative' THEN
836 NEW.rank_address := NEW.rank_search;
838 NEW.rank_address := 0;
840 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
841 NEW.rank_search := 22;
842 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
843 NEW.rank_address := NEW.rank_search;
845 NEW.rank_address := 0;
847 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
848 NEW.rank_search := 18;
849 NEW.rank_address := 0;
850 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
851 NEW.rank_search := 4;
852 NEW.rank_address := NEW.rank_search;
853 -- any feature more than 5 square miles is probably worth indexing
854 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
855 NEW.rank_search := 22;
856 NEW.rank_address := 0;
857 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
859 ELSEIF NEW.class = 'waterway' THEN
860 IF NEW.osm_type = 'R' THEN
861 NEW.rank_search := 16;
863 NEW.rank_search := 17;
865 NEW.rank_address := 0;
866 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
867 NEW.rank_search := 27;
868 NEW.rank_address := NEW.rank_search;
869 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
870 NEW.rank_search := 26;
871 NEW.rank_address := NEW.rank_search;
872 ELSEIF NEW.class = 'mountain_pass' THEN
873 NEW.rank_search := 20;
874 NEW.rank_address := 0;
879 IF NEW.rank_search > 30 THEN
880 NEW.rank_search := 30;
883 IF NEW.rank_address > 30 THEN
884 NEW.rank_address := 30;
887 IF (NEW.extratags -> 'capital') = 'yes' THEN
888 NEW.rank_search := NEW.rank_search - 1;
891 -- a country code make no sense below rank 4 (country)
892 IF NEW.rank_search < 4 THEN
893 NEW.country_code := NULL;
896 -- Block import below rank 22
897 -- IF NEW.rank_search > 22 THEN
901 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
903 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
905 IF NEW.rank_address > 0 THEN
906 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
907 -- Performance: We just can't handle re-indexing for country level changes
908 IF st_area(NEW.geometry) < 1 THEN
909 -- mark items within the geometry for re-indexing
910 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
912 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
913 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
914 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
915 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
916 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
919 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
921 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
922 IF NEW.type='postcode' THEN
924 ELSEIF NEW.rank_search < 16 THEN
926 ELSEIF NEW.rank_search < 18 THEN
928 ELSEIF NEW.rank_search < 20 THEN
930 ELSEIF NEW.rank_search = 21 THEN
932 ELSEIF NEW.rank_search < 24 THEN
934 ELSEIF NEW.rank_search < 26 THEN
935 diameter := 0.002; -- 100 to 200 meters
936 ELSEIF NEW.rank_search < 28 THEN
937 diameter := 0.001; -- 50 to 100 meters
940 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
941 IF NEW.rank_search >= 26 THEN
942 -- roads may cause reparenting for >27 rank places
943 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
944 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
945 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
946 ELSEIF NEW.rank_search >= 16 THEN
947 -- up to rank 16, street-less addresses may need reparenting
948 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or address ? 'place');
950 -- for all other places the search terms may change as well
951 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);
958 -- add to tables for special search
959 -- Note: won't work on initial import because the classtype tables
960 -- do not yet exist. It won't hurt either.
961 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
962 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
964 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
965 USING NEW.place_id, ST_Centroid(NEW.geometry);
974 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
978 place_centroid GEOMETRY;
992 IF OLD.indexed_status = 100 THEN
993 delete from location_property_osmline where place_id = OLD.place_id;
997 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1001 NEW.interpolationtype = NEW.address->'interpolation';
1003 place_centroid := ST_PointOnSurface(NEW.linegeo);
1004 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1005 NEW.address->'place',
1006 NEW.partition, place_centroid, NEW.linegeo);
1009 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1010 NEW.postcode = NEW.address->'postcode';
1013 -- if the line was newly inserted, split the line as necessary
1014 IF OLD.indexed_status = 1 THEN
1015 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1017 IF array_upper(waynodes, 1) IS NULL THEN
1021 linegeo := NEW.linegeo;
1022 startnumber := NULL;
1023 postcode := NEW.postcode;
1025 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1027 select osm_id, address, geometry
1028 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1029 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1030 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1031 IF nextnode.osm_id IS NOT NULL THEN
1032 --RAISE NOTICE 'place_id is not null';
1033 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1034 -- Make sure that the point is actually on the line. That might
1035 -- be a bit paranoid but ensures that the algorithm still works
1036 -- should osm2pgsql attempt to repair geometries.
1037 splitline := split_line_on_node(linegeo, nextnode.geometry);
1038 sectiongeo := ST_GeometryN(splitline, 1);
1039 linegeo := ST_GeometryN(splitline, 2);
1041 sectiongeo = linegeo;
1043 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1045 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1046 AND startnumber != endnumber
1047 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1049 IF (startnumber > endnumber) THEN
1050 housenum := endnumber;
1051 endnumber := startnumber;
1052 startnumber := housenum;
1053 sectiongeo := ST_Reverse(sectiongeo);
1056 seg_postcode := coalesce(postcode,
1057 prevnode.address->'postcode',
1058 nextnode.address->'postcode');
1060 IF NEW.startnumber IS NULL THEN
1061 NEW.startnumber := startnumber;
1062 NEW.endnumber := endnumber;
1063 NEW.linegeo := sectiongeo;
1064 NEW.postcode := seg_postcode;
1066 insert into location_property_osmline
1067 (linegeo, partition, osm_id, parent_place_id,
1068 startnumber, endnumber, interpolationtype,
1069 address, postcode, country_code,
1070 geometry_sector, indexed_status)
1071 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1072 startnumber, endnumber, NEW.interpolationtype,
1073 NEW.address, seg_postcode,
1074 NEW.country_code, NEW.geometry_sector, 0);
1078 -- early break if we are out of line string,
1079 -- might happen when a line string loops back on itself
1080 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1084 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1085 prevnode := nextnode;
1090 -- marking descendants for reparenting is not needed, because there are
1091 -- actually no descendants for interpolation lines
1099 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1104 place_centroid GEOMETRY;
1106 search_maxdistance FLOAT[];
1107 search_mindistance FLOAT[];
1108 address_havelevel BOOLEAN[];
1115 relation_members TEXT[];
1117 linkedplacex RECORD;
1118 search_diameter FLOAT;
1119 search_prevdiameter FLOAT;
1120 search_maxrank INTEGER;
1121 address_maxrank INTEGER;
1122 address_street_word_id INTEGER;
1123 address_street_word_ids INTEGER[];
1124 parent_place_id_rank BIGINT;
1132 location_rank_search INTEGER;
1133 location_distance FLOAT;
1134 location_parent GEOMETRY;
1135 location_isaddress BOOLEAN;
1136 location_keywords INTEGER[];
1138 default_language TEXT;
1139 name_vector INTEGER[];
1140 nameaddress_vector INTEGER[];
1142 linked_node_id BIGINT;
1143 linked_importance FLOAT;
1144 linked_wikipedia TEXT;
1149 IF OLD.indexed_status = 100 THEN
1150 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1151 delete from placex where place_id = OLD.place_id;
1155 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1159 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1161 --RAISE WARNING '%',NEW.place_id;
1162 --RAISE WARNING '%', NEW;
1164 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1165 -- Silently do nothing
1169 NEW.indexed_date = now();
1171 result := deleteSearchName(NEW.partition, NEW.place_id);
1172 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1173 result := deleteRoad(NEW.partition, NEW.place_id);
1174 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1175 UPDATE placex set linked_place_id = null, indexed_status = 2
1176 where linked_place_id = NEW.place_id;
1177 -- update not necessary for osmline, cause linked_place_id does not exist
1179 IF NEW.linked_place_id is not null THEN
1183 IF NEW.address is not NULL THEN
1184 IF NEW.address ? 'conscriptionnumber' THEN
1185 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1186 IF NEW.address ? 'streetnumber' THEN
1187 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1188 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1190 NEW.housenumber := NEW.address->'conscriptionnumber';
1192 ELSEIF NEW.address ? 'streetnumber' THEN
1193 NEW.housenumber := NEW.address->'streetnumber';
1194 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1195 ELSEIF NEW.address ? 'housenumber' THEN
1196 NEW.housenumber := NEW.address->'housenumber';
1197 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1200 addr_street = NEW.address->'street';
1201 addr_place = NEW.address->'place';
1203 NEW.postcode = NEW.address->'postcode';
1206 -- Speed up searches - just use the centroid of the feature
1207 -- cheaper but less acurate
1208 place_centroid := ST_PointOnSurface(NEW.geometry);
1209 NEW.centroid := null;
1211 -- recalculate country and partition
1212 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1213 -- for countries, believe the mapped country code,
1214 -- so that we remain in the right partition if the boundaries
1216 NEW.country_code := lower(NEW.address->'country');
1217 NEW.partition := get_partition(lower(NEW.country_code));
1218 IF NEW.partition = 0 THEN
1219 NEW.country_code := lower(get_country_code(place_centroid));
1220 NEW.partition := get_partition(NEW.country_code);
1223 IF NEW.rank_search >= 4 THEN
1224 NEW.country_code := lower(get_country_code(place_centroid));
1226 NEW.country_code := NULL;
1228 NEW.partition := get_partition(NEW.country_code);
1231 -- waterway ways are linked when they are part of a relation and have the same class/type
1232 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1233 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1235 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1236 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1237 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1238 FOR linked_node_id IN SELECT place_id FROM placex
1239 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1240 and class = NEW.class and type = NEW.type
1241 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1243 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1250 -- Adding ourselves to the list simplifies address calculations later
1251 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1252 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1254 -- What level are we searching from
1255 search_maxrank := NEW.rank_search;
1257 -- Thought this wasn't needed but when we add new languages to the country_name table
1258 -- we need to update the existing names
1259 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1260 default_language := get_country_language_code(NEW.country_code);
1261 IF default_language IS NOT NULL THEN
1262 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1263 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1264 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1265 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1270 -- Initialise the name vector using our name
1271 name_vector := make_keywords(NEW.name);
1272 nameaddress_vector := '{}'::int[];
1275 address_havelevel[i] := false;
1278 NEW.importance := null;
1279 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1280 IF NEW.importance IS NULL THEN
1281 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;
1284 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1286 -- ---------------------------------------------------------------------------
1287 -- For low level elements we inherit from our parent road
1288 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1290 --RAISE WARNING 'finding street for %', NEW;
1292 -- We won't get a better centroid, besides these places are too small to care
1293 NEW.centroid := place_centroid;
1295 NEW.parent_place_id := null;
1297 -- if we have a POI and there is no address information,
1298 -- see if we can get it from a surrounding building
1299 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1300 AND NEW.housenumber IS NULL THEN
1301 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1302 and address is not null
1303 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1304 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1307 NEW.housenumber := location.address->'housenumber';
1308 addr_street := location.address->'street';
1309 addr_place := location.address->'place';
1313 -- We have to find our parent road.
1314 -- Copy data from linked items (points on ways, addr:street links, relations)
1316 -- Is this object part of a relation?
1317 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1319 -- At the moment we only process one type of relation - associatedStreet
1320 IF relation.tags @> ARRAY['associatedStreet'] THEN
1321 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1322 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1323 --RAISE WARNING 'node in relation %',relation;
1324 SELECT place_id from placex where osm_type = 'W'
1325 and osm_id = substring(relation.members[i],2,200)::bigint
1326 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1333 -- Note that addr:street links can only be indexed once the street itself is indexed
1334 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1335 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1336 IF address_street_word_ids IS NOT NULL THEN
1337 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1338 NEW.parent_place_id := location.place_id;
1343 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1344 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1345 IF address_street_word_ids IS NOT NULL THEN
1346 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1347 NEW.parent_place_id := location.place_id;
1352 -- Is this node part of an interpolation?
1353 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1355 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1356 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1359 NEW.parent_place_id := location.parent_place_id;
1363 -- Is this node part of a way?
1364 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1366 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.address from placex p, planet_osm_ways w
1367 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)
1370 -- Way IS a road then we are on it - that must be our road
1371 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1372 --RAISE WARNING 'node in way that is a street %',location;
1373 NEW.parent_place_id := location.place_id;
1376 -- If the way mentions a street or place address, try that for parenting.
1377 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1378 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1379 IF address_street_word_ids IS NOT NULL THEN
1380 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1381 NEW.parent_place_id := linkedplacex.place_id;
1386 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1387 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1388 IF address_street_word_ids IS NOT NULL THEN
1389 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1390 NEW.parent_place_id := linkedplacex.place_id;
1395 -- Is the WAY part of a relation
1396 IF NEW.parent_place_id IS NULL THEN
1397 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1399 -- At the moment we only process one type of relation - associatedStreet
1400 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1401 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1402 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1403 --RAISE WARNING 'node in way that is in a relation %',relation;
1404 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1405 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1416 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1417 -- Still nothing, just use the nearest road
1418 IF NEW.parent_place_id IS NULL THEN
1419 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1420 NEW.parent_place_id := location.place_id;
1425 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1427 -- If we didn't find any road fallback to standard method
1428 IF NEW.parent_place_id IS NOT NULL THEN
1430 -- Get the details of the parent road
1431 select * from search_name where place_id = NEW.parent_place_id INTO location;
1432 NEW.country_code := location.country_code;
1434 -- Merge the postcode into the parent's address if necessary
1435 IF NEW.postcode IS NOT NULL THEN
1436 isin_tokens := '{}'::int[];
1437 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1438 IF address_street_word_id is not null
1439 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1440 isin_tokens := isin_tokens || address_street_word_id;
1442 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1443 IF address_street_word_id is not null
1444 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1445 isin_tokens := isin_tokens || address_street_word_id;
1447 IF isin_tokens != '{}'::int[] THEN
1449 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1450 WHERE place_id = NEW.parent_place_id;
1454 --RAISE WARNING '%', NEW.name;
1455 -- If there is no name it isn't searchable, don't bother to create a search record
1456 IF NEW.name is NULL THEN
1460 -- Merge address from parent
1461 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1462 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1464 -- Performance, it would be more acurate to do all the rest of the import
1465 -- process but it takes too long
1466 -- Just be happy with inheriting from parent road only
1468 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1469 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1472 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1479 -- RAISE WARNING ' INDEXING Started:';
1480 -- RAISE WARNING ' INDEXING: %',NEW;
1482 -- ---------------------------------------------------------------------------
1485 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1487 -- see if we have any special relation members
1488 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1490 -- RAISE WARNING 'get_osm_rel_members, label';
1491 IF relation_members IS NOT NULL THEN
1492 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1494 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1495 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1497 -- If we don't already have one use this as the centre point of the geometry
1498 IF NEW.centroid IS NULL THEN
1499 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1502 -- merge in the label name, re-init word vector
1503 IF NOT linkedPlacex.name IS NULL THEN
1504 NEW.name := linkedPlacex.name || NEW.name;
1505 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1508 -- merge in extra tags
1509 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1511 -- mark the linked place (excludes from search results)
1512 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1514 -- keep a note of the node id in case we need it for wikipedia in a bit
1515 linked_node_id := linkedPlacex.osm_id;
1516 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1521 IF NEW.centroid IS NULL THEN
1523 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1525 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1526 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1528 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1529 -- But that can be fixed by explicitly setting the label in the data
1530 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1531 AND NEW.rank_address = linkedPlacex.rank_address THEN
1533 -- If we don't already have one use this as the centre point of the geometry
1534 IF NEW.centroid IS NULL THEN
1535 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1538 -- merge in the name, re-init word vector
1539 IF NOT linkedPlacex.name IS NULL THEN
1540 NEW.name := linkedPlacex.name || NEW.name;
1541 name_vector := make_keywords(NEW.name);
1544 -- merge in extra tags
1545 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1547 -- mark the linked place (excludes from search results)
1548 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1550 -- keep a note of the node id in case we need it for wikipedia in a bit
1551 linked_node_id := linkedPlacex.osm_id;
1552 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1564 -- Name searches can be done for ways as well as relations
1565 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1567 -- not found one yet? how about doing a name search
1568 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1570 FOR linkedPlacex IN select placex.* from placex WHERE
1571 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1572 AND placex.rank_address = NEW.rank_address
1573 AND placex.place_id != NEW.place_id
1574 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1575 AND st_covers(NEW.geometry, placex.geometry)
1578 -- If we don't already have one use this as the centre point of the geometry
1579 IF NEW.centroid IS NULL THEN
1580 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1583 -- merge in the name, re-init word vector
1584 NEW.name := linkedPlacex.name || NEW.name;
1585 name_vector := make_keywords(NEW.name);
1587 -- merge in extra tags
1588 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1590 -- mark the linked place (excludes from search results)
1591 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1593 -- keep a note of the node id in case we need it for wikipedia in a bit
1594 linked_node_id := linkedPlacex.osm_id;
1595 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1599 IF NEW.centroid IS NOT NULL THEN
1600 place_centroid := NEW.centroid;
1601 -- Place might have had only a name tag before but has now received translations
1602 -- from the linked place. Make sure a name tag for the default language exists in
1604 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1605 default_language := get_country_language_code(NEW.country_code);
1606 IF default_language IS NOT NULL THEN
1607 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1608 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1609 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1610 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1616 -- Use the maximum importance if a one could be computed from the linked object.
1617 IF linked_importance is not null AND
1618 (NEW.importance is null or NEW.importance < linked_importance) THEN
1619 NEW.importance = linked_importance;
1622 -- Still null? how about looking it up by the node id
1623 IF NEW.importance IS NULL THEN
1624 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;
1629 -- make sure all names are in the word table
1630 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1631 perform create_country(NEW.name, lower(NEW.country_code));
1634 NEW.parent_place_id = 0;
1635 parent_place_id_rank = 0;
1638 -- convert isin to array of tokenids
1639 isin_tokens := '{}'::int[];
1640 IF NEW.address IS NOT NULL THEN
1641 isin := avals(NEW.address);
1642 IF array_upper(isin, 1) IS NOT NULL THEN
1643 FOR i IN 1..array_upper(isin, 1) LOOP
1644 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1645 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1646 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1647 isin_tokens := isin_tokens || address_street_word_id;
1650 -- merge word into address vector
1651 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1652 IF address_street_word_id IS NOT NULL THEN
1653 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1658 IF NEW.postcode IS NOT NULL THEN
1659 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1660 IF array_upper(isin, 1) IS NOT NULL THEN
1661 FOR i IN 1..array_upper(isin, 1) LOOP
1662 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1663 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1664 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1665 isin_tokens := isin_tokens || address_street_word_id;
1668 -- merge into address vector
1669 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1670 IF address_street_word_id IS NOT NULL THEN
1671 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1677 -- %NOTIGERDATA% IF 0 THEN
1678 -- for the USA we have an additional address table. Merge in zip codes from there too
1679 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1680 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1681 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1682 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1683 isin_tokens := isin_tokens || address_street_word_id;
1685 -- also merge in the single word version
1686 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1687 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1690 -- %NOTIGERDATA% END IF;
1692 -- RAISE WARNING 'ISIN: %', isin_tokens;
1694 -- Process area matches
1695 location_rank_search := 0;
1696 location_distance := 0;
1697 location_parent := NULL;
1698 -- added ourself as address already
1699 address_havelevel[NEW.rank_address] := true;
1700 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1702 SELECT * from getNearFeatures(NEW.partition,
1703 CASE WHEN NEW.rank_search >= 26
1704 AND NEW.rank_search < 30
1706 ELSE place_centroid END,
1707 search_maxrank, isin_tokens)
1710 --RAISE WARNING ' AREA: %',location;
1712 IF location.rank_address != location_rank_search THEN
1713 location_rank_search := location.rank_address;
1714 IF location.isguess THEN
1715 location_distance := location.distance * 1.5;
1717 IF location.rank_address <= 12 THEN
1718 -- for county and above, if we have an area consider that exact
1719 -- (It would be nice to relax the constraint for places close to
1720 -- the boundary but we'd need the exact geometry for that. Too
1722 location_distance = 0;
1724 -- Below county level remain slightly fuzzy.
1725 location_distance := location.distance * 0.5;
1729 CONTINUE WHEN location.keywords <@ location_keywords;
1732 IF location.distance < location_distance OR NOT location.isguess THEN
1733 location_keywords := location.keywords;
1735 location_isaddress := NOT address_havelevel[location.rank_address];
1736 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1737 location_isaddress := ST_Contains(location_parent,location.centroid);
1740 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1741 -- Add it to the list of search terms
1742 IF location.rank_search > 4 THEN
1743 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1745 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1746 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1748 IF location_isaddress THEN
1750 address_havelevel[location.rank_address] := true;
1751 IF NOT location.isguess THEN
1752 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1755 IF location.rank_address > parent_place_id_rank THEN
1756 NEW.parent_place_id = location.place_id;
1757 parent_place_id_rank = location.rank_address;
1762 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1768 -- try using the isin value to find parent places
1769 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1770 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1771 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1772 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1774 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1776 --RAISE WARNING ' ISIN: %',location;
1778 IF location.rank_search > 4 THEN
1779 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1780 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1781 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1782 address_havelevel[location.rank_address] := true;
1784 IF location.rank_address > parent_place_id_rank THEN
1785 NEW.parent_place_id = location.place_id;
1786 parent_place_id_rank = location.rank_address;
1796 -- for long ways we should add search terms for the entire length
1797 IF st_length(NEW.geometry) > 0.05 THEN
1799 location_rank_search := 0;
1800 location_distance := 0;
1802 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1804 IF location.rank_address != location_rank_search THEN
1805 location_rank_search := location.rank_address;
1806 location_distance := location.distance * 1.5;
1809 IF location.rank_search > 4 AND location.distance < location_distance THEN
1811 -- Add it to the list of search terms
1812 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1813 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1814 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1822 -- if we have a name add this to the name search table
1823 IF NEW.name IS NOT NULL THEN
1825 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1826 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1829 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1830 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1833 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1837 -- If we've not managed to pick up a better one - default centroid
1838 IF NEW.centroid IS NULL THEN
1839 NEW.centroid := place_centroid;
1847 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1853 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1855 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1856 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1857 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1858 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1860 IF OLD.rank_address < 30 THEN
1862 -- mark everything linked to this place for re-indexing
1863 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1864 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1865 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1867 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1868 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1870 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1871 b := deleteRoad(OLD.partition, OLD.place_id);
1873 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1874 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1875 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1876 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1877 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1881 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1883 IF OLD.rank_address < 26 THEN
1884 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1887 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1889 IF OLD.name is not null THEN
1890 b := deleteSearchName(OLD.partition, OLD.place_id);
1893 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1895 DELETE FROM place_addressline where place_id = OLD.place_id;
1897 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1899 -- remove from tables for special search
1900 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1901 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1903 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1906 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1914 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1920 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1922 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1923 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1924 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;
1926 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1932 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;
1934 -- interpolations are special
1935 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1936 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1945 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1950 existingplacex RECORD;
1951 existingline RECORD;
1952 existinggeometry GEOMETRY;
1953 existingplace_id BIGINT;
1958 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1959 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1960 -- filter wrong tupels
1961 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
1962 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
1963 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1964 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1968 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
1969 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1970 -- Have we already done this place?
1971 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;
1973 -- Get the existing place_id
1974 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1976 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1977 IF existing.osm_type IS NULL THEN
1978 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1981 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1982 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1984 -- 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)
1985 IF existingline.osm_id IS NOT NULL THEN
1986 delete from location_property_osmline where osm_id = NEW.osm_id;
1989 -- for interpolations invalidate all nodes on the line
1990 update placex p set indexed_status = 2
1991 from planet_osm_ways w
1992 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
1995 INSERT INTO location_property_osmline (osm_id, address, linegeo)
1996 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
1999 IF existing.osm_type IS NULL THEN
2003 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2004 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2005 OR existing.geometry::text != NEW.geometry::text
2010 address = NEW.address,
2011 extratags = NEW.extratags,
2012 admin_level = NEW.admin_level,
2013 geometry = NEW.geometry
2014 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2019 ELSE -- insert to placex
2021 -- Patch in additional country names
2022 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2023 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2024 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2025 IF existing.name IS NOT NULL THEN
2026 NEW.name = existing.name || NEW.name;
2030 -- Have we already done this place?
2031 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;
2033 -- Get the existing place_id
2034 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;
2036 -- Handle a place changing type by removing the old data
2037 -- My generated 'place' types are causing havok because they overlap with real keys
2038 -- TODO: move them to their own special purpose key/class to avoid collisions
2039 IF existing.osm_type IS NULL THEN
2040 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2043 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2044 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2047 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2048 AND st_area(existing.geometry) > 0.02
2049 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2050 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2052 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2053 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2054 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2058 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2059 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2061 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2062 IF existingplacex.osm_type IS NULL OR
2063 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2066 IF existingplacex.osm_type IS NOT NULL THEN
2067 -- sanity check: ignore admin_level changes on places with too many active children
2068 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2069 --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;
2070 --LIMIT INDEXING: IF i > 100000 THEN
2071 --LIMIT INDEXING: RETURN null;
2072 --LIMIT INDEXING: END IF;
2075 IF existing.osm_type IS NOT NULL THEN
2076 -- pathological case caused by the triggerless copy into place during initial import
2077 -- force delete even for large areas, it will be reinserted later
2078 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;
2079 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2082 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2083 insert into placex (osm_type, osm_id, class, type, name,
2084 admin_level, address, extratags, geometry)
2085 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2086 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2088 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2093 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2094 IF existing.geometry::text != NEW.geometry::text
2095 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2096 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2099 -- Get the version of the geometry actually used (in placex table)
2100 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;
2102 -- Performance limit
2103 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2105 -- 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
2106 update placex set indexed_status = 2 where indexed_status = 0 and
2107 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2108 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2109 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2111 update placex set indexed_status = 2 where indexed_status = 0 and
2112 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2113 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2114 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2121 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2122 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2123 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2124 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2125 OR existing.geometry::text != NEW.geometry::text
2130 address = NEW.address,
2131 extratags = NEW.extratags,
2132 admin_level = NEW.admin_level,
2133 geometry = NEW.geometry
2134 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2137 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2138 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2139 -- postcode was deleted, no longer retain in placex
2140 DELETE FROM placex where place_id = existingplacex.place_id;
2144 NEW.name := hstore('ref', NEW.address->'postcode');
2149 address = NEW.address,
2150 parent_place_id = null,
2151 extratags = NEW.extratags,
2152 admin_level = NEW.admin_level,
2154 geometry = NEW.geometry
2155 where place_id = existingplacex.place_id;
2157 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2158 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2159 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2160 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2161 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);
2166 -- Abort the add (we modified the existing place instead)
2171 $$ LANGUAGE plpgsql;
2174 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2179 IF name is null THEN
2183 FOR j IN 1..array_upper(languagepref,1) LOOP
2184 IF name ? languagepref[j] THEN
2185 result := trim(name->languagepref[j]);
2186 IF result != '' THEN
2192 -- anything will do as a fallback - just take the first name type thing there is
2193 RETURN trim((avals(name))[1]);
2196 LANGUAGE plpgsql IMMUTABLE;
2199 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2210 search := ARRAY['ref'];
2213 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2216 select rank_address,name,distance,length(name::text) as namelength
2217 from place_addressline join placex on (address_place_id = placex.place_id)
2218 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2219 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2221 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2222 FOR j IN 1..array_upper(search, 1) LOOP
2223 FOR k IN 1..array_upper(location.name, 1) LOOP
2224 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
2225 result[(100 - location.rank_address)] := trim(location.name[k].value);
2226 found := location.rank_address;
2233 RETURN array_to_string(result,', ');
2238 --housenumber only needed for tiger data
2239 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2251 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2252 currresult := trim(get_name_by_language(location.name, languagepref));
2253 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2254 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2255 prevresult := currresult;
2259 RETURN array_to_string(result,', ');
2264 DROP TYPE IF EXISTS addressline CASCADE;
2265 create type addressline as (
2272 admin_level INTEGER,
2275 rank_address INTEGER,
2279 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2282 for_place_id BIGINT;
2287 countrylocation RECORD;
2288 searchcountrycode varchar(2);
2289 searchhousenumber TEXT;
2290 searchhousename HSTORE;
2291 searchrankaddress INTEGER;
2292 searchpostcode TEXT;
2298 -- first query osmline (interpolation lines)
2299 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2300 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2301 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2302 IF for_place_id IS NOT NULL THEN
2303 searchhousenumber = in_housenumber::text;
2306 --then query tiger data
2307 -- %NOTIGERDATA% IF 0 THEN
2308 IF for_place_id IS NULL THEN
2309 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2310 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2311 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2312 IF for_place_id IS NOT NULL THEN
2313 searchhousenumber = in_housenumber::text;
2316 -- %NOTIGERDATA% END IF;
2318 -- %NOAUXDATA% IF 0 THEN
2319 IF for_place_id IS NULL THEN
2320 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2321 WHERE place_id = in_place_id
2322 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2324 -- %NOAUXDATA% END IF;
2326 IF for_place_id IS NULL THEN
2327 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2328 WHERE place_id = in_place_id and rank_search > 27
2329 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2332 IF for_place_id IS NULL THEN
2333 select coalesce(linked_place_id, place_id), country_code,
2334 housenumber, rank_search, postcode, null
2335 from placex where place_id = in_place_id
2336 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2339 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2342 hadcountry := false;
2344 select placex.place_id, osm_type, osm_id,
2345 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2346 class, type, admin_level, true as fromarea, true as isaddress,
2347 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2348 0 as distance, country_code, postcode
2350 where place_id = for_place_id
2352 --RAISE WARNING '%',location;
2353 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2354 searchcountrycode := location.country_code;
2356 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2357 location.isaddress := FALSE;
2359 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2360 searchpostcode := location.postcode;
2362 IF location.rank_address = 4 AND location.isaddress THEN
2365 IF location.rank_address < 4 AND NOT hadcountry THEN
2366 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2367 IF countryname IS NOT NULL THEN
2368 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2369 RETURN NEXT countrylocation;
2372 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2373 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2374 location.distance)::addressline;
2375 RETURN NEXT countrylocation;
2376 found := location.rank_address;
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 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2383 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2384 admin_level, fromarea, isaddress,
2385 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,
2386 distance,country_code,postcode
2387 from place_addressline join placex on (address_place_id = placex.place_id)
2388 where place_addressline.place_id = for_place_id
2389 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2390 and address_place_id != for_place_id
2391 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2392 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2394 --RAISE WARNING '%',location;
2395 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2396 searchcountrycode := location.country_code;
2398 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2399 location.isaddress := FALSE;
2401 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2402 searchpostcode := location.postcode;
2404 IF location.rank_address = 4 AND location.isaddress THEN
2407 IF location.rank_address < 4 AND NOT hadcountry THEN
2408 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2409 IF countryname IS NOT NULL THEN
2410 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2411 RETURN NEXT countrylocation;
2414 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2415 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2416 location.distance)::addressline;
2417 RETURN NEXT countrylocation;
2418 found := location.rank_address;
2422 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2423 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2424 IF countryname IS NOT NULL THEN
2425 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2426 RETURN NEXT location;
2430 IF searchcountrycode IS NOT NULL THEN
2431 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2432 RETURN NEXT location;
2435 IF searchhousename IS NOT NULL THEN
2436 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2437 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2438 RETURN NEXT location;
2441 IF searchhousenumber IS NOT NULL THEN
2442 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2443 RETURN NEXT location;
2446 IF searchpostcode IS NOT NULL THEN
2447 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2448 RETURN NEXT location;
2457 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2463 ELSEIF rank < 4 THEN
2465 ELSEIF rank < 8 THEN
2467 ELSEIF rank < 12 THEN
2469 ELSEIF rank < 16 THEN
2471 ELSEIF rank = 16 THEN
2473 ELSEIF rank = 17 THEN
2474 RETURN 'Town / Island';
2475 ELSEIF rank = 18 THEN
2476 RETURN 'Village / Hamlet';
2477 ELSEIF rank = 20 THEN
2479 ELSEIF rank = 21 THEN
2480 RETURN 'Postcode Area';
2481 ELSEIF rank = 22 THEN
2482 RETURN 'Croft / Farm / Locality / Islet';
2483 ELSEIF rank = 23 THEN
2484 RETURN 'Postcode Area';
2485 ELSEIF rank = 25 THEN
2486 RETURN 'Postcode Point';
2487 ELSEIF rank = 26 THEN
2488 RETURN 'Street / Major Landmark';
2489 ELSEIF rank = 27 THEN
2490 RETURN 'Minory Street / Path';
2491 ELSEIF rank = 28 THEN
2492 RETURN 'House / Building';
2494 RETURN 'Other: '||rank;
2501 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2507 ELSEIF rank < 2 THEN
2509 ELSEIF rank < 4 THEN
2511 ELSEIF rank = 5 THEN
2513 ELSEIF rank < 8 THEN
2515 ELSEIF rank < 12 THEN
2517 ELSEIF rank < 16 THEN
2519 ELSEIF rank = 16 THEN
2521 ELSEIF rank = 17 THEN
2522 RETURN 'Town / Village / Hamlet';
2523 ELSEIF rank = 20 THEN
2525 ELSEIF rank = 21 THEN
2526 RETURN 'Postcode Area';
2527 ELSEIF rank = 22 THEN
2528 RETURN 'Croft / Farm / Locality / Islet';
2529 ELSEIF rank = 23 THEN
2530 RETURN 'Postcode Area';
2531 ELSEIF rank = 25 THEN
2532 RETURN 'Postcode Point';
2533 ELSEIF rank = 26 THEN
2534 RETURN 'Street / Major Landmark';
2535 ELSEIF rank = 27 THEN
2536 RETURN 'Minory Street / Path';
2537 ELSEIF rank = 28 THEN
2538 RETURN 'House / Building';
2540 RETURN 'Other: '||rank;
2547 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2548 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2553 place_centroid GEOMETRY;
2554 out_partition INTEGER;
2555 out_parent_place_id BIGINT;
2557 address_street_word_id INTEGER;
2562 place_centroid := ST_Centroid(pointgeo);
2563 out_partition := get_partition(in_countrycode);
2564 out_parent_place_id := null;
2566 address_street_word_id := get_name_id(make_standard_name(in_street));
2567 IF address_street_word_id IS NOT NULL THEN
2568 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2569 out_parent_place_id := location.place_id;
2573 IF out_parent_place_id IS NULL THEN
2574 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2575 out_parent_place_id := location.place_id;
2579 out_postcode := in_postcode;
2580 IF out_postcode IS NULL THEN
2581 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2583 IF out_postcode IS NULL THEN
2584 out_postcode := getNearestPostcode(out_partition, place_centroid);
2588 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2589 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2590 newpoints := newpoints + 1;
2597 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2604 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2605 IF members[i+1] = member THEN
2606 result := result || members[i];
2615 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2621 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2622 IF members[i+1] = ANY(memberLabels) THEN
2623 RETURN NEXT members[i];
2632 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2633 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2635 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2636 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
2637 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2638 ), '') AS bytea), 'UTF8');
2640 LANGUAGE SQL IMMUTABLE STRICT;
2642 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2646 RETURN decode_url_part(p);
2648 WHEN others THEN return null;
2651 LANGUAGE plpgsql IMMUTABLE;
2653 DROP TYPE wikipedia_article_match CASCADE;
2654 create type wikipedia_article_match as (
2660 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2666 wiki_article_title TEXT;
2667 wiki_article_language TEXT;
2668 result wikipedia_article_match;
2670 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'];
2672 WHILE langs[i] IS NOT NULL LOOP
2673 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2674 IF wiki_article is not null THEN
2675 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2676 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2677 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2678 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2679 wiki_article := replace(wiki_article,' ','_');
2680 IF strpos(wiki_article, ':') IN (3,4) THEN
2681 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2682 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2684 wiki_article_title := trim(wiki_article);
2685 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;
2688 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2689 from wikipedia_article
2690 where language = wiki_article_language and
2691 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2693 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2694 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2695 where wikipedia_redirect.language = wiki_article_language and
2696 (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'\\',''))
2697 order by importance desc limit 1 INTO result;
2699 IF result.language is not null THEN
2710 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2711 RETURNS SETOF GEOMETRY
2725 remainingdepth INTEGER;
2730 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2732 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2733 RETURN NEXT geometry;
2737 remainingdepth := maxdepth - 1;
2738 area := ST_AREA(geometry);
2739 IF remainingdepth < 1 OR area < maxarea THEN
2740 RETURN NEXT geometry;
2744 xmin := st_xmin(geometry);
2745 xmax := st_xmax(geometry);
2746 ymin := st_ymin(geometry);
2747 ymax := st_ymax(geometry);
2748 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2750 -- if the geometry completely covers the box don't bother to slice any more
2751 IF ST_AREA(secbox) = area THEN
2752 RETURN NEXT geometry;
2756 xmid := (xmin+xmax)/2;
2757 ymid := (ymin+ymax)/2;
2760 FOR seg IN 1..4 LOOP
2763 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2766 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2769 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2772 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2775 IF st_intersects(geometry, secbox) THEN
2776 secgeo := st_intersection(geometry, secbox);
2777 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2778 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2779 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2781 RETURN NEXT geo.geom;
2793 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2794 RETURNS SETOF GEOMETRY
2799 -- 10000000000 is ~~ 1x1 degree
2800 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2801 RETURN NEXT geo.geom;
2809 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2813 osmtype character(1);
2817 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2818 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2819 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2820 -- force delete from place/placex by making it a very small geometry
2821 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;
2822 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2829 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2837 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2838 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2839 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2840 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2841 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2842 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2843 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address > 'place'));
2844 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2845 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and address ? 'place'));
2851 ELSEIF rank < 18 THEN
2853 ELSEIF rank < 20 THEN
2855 ELSEIF rank = 21 THEN
2857 ELSEIF rank < 24 THEN
2859 ELSEIF rank < 26 THEN
2860 diameter := 0.002; -- 100 to 200 meters
2861 ELSEIF rank < 28 THEN
2862 diameter := 0.001; -- 50 to 100 meters
2864 IF diameter > 0 THEN
2866 -- roads may cause reparenting for >27 rank places
2867 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2868 ELSEIF rank >= 16 THEN
2869 -- up to rank 16, street-less addresses may need reparenting
2870 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or address ? 'place');
2872 -- for all other places the search terms may change as well
2873 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);