1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
91 return_word_id INTEGER;
93 lookup_token := ' '||trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
145 nospace_lookup_token TEXT;
146 return_word_id INTEGER;
148 lookup_token := ' '||trim(lookup_word);
149 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
150 IF return_word_id IS NULL THEN
151 return_word_id := nextval('seq_word');
152 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
153 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
154 -- IF ' '||nospace_lookup_token != lookup_token THEN
155 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
168 RETURN getorcreate_name_id(lookup_word, '');
173 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
178 return_word_id INTEGER;
180 lookup_token := trim(lookup_word);
181 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
182 RETURN return_word_id;
185 LANGUAGE plpgsql IMMUTABLE;
187 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
192 return_word_id INTEGER;
194 lookup_token := ' '||trim(lookup_word);
195 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
196 RETURN return_word_id;
199 LANGUAGE plpgsql IMMUTABLE;
201 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
206 return_word_ids INTEGER[];
208 lookup_token := ' '||trim(lookup_word);
209 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
210 RETURN return_word_ids;
213 LANGUAGE plpgsql IMMUTABLE;
215 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
222 IF array_upper(a, 1) IS NULL THEN
225 IF array_upper(b, 1) IS NULL THEN
229 FOR i IN 1..array_upper(b, 1) LOOP
230 IF NOT (ARRAY[b[i]] <@ r) THEN
237 LANGUAGE plpgsql IMMUTABLE;
239 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
248 FOR item IN SELECT (each(src)).* LOOP
250 s := make_standard_name(item.value);
251 w := getorcreate_country(s, lookup_country_code);
253 words := regexp_split_to_array(item.value, E'[,;()]');
254 IF array_upper(words, 1) != 1 THEN
255 FOR j IN 1..array_upper(words, 1) LOOP
256 s := make_standard_name(words[j]);
258 w := getorcreate_country(s, lookup_country_code);
267 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
277 result := '{}'::INTEGER[];
279 FOR item IN SELECT (each(src)).* LOOP
281 s := make_standard_name(item.value);
283 w := getorcreate_name_id(s, item.value);
285 IF not(ARRAY[w] <@ result) THEN
286 result := result || w;
289 w := getorcreate_word_id(s);
291 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
292 result := result || w;
295 words := string_to_array(s, ' ');
296 IF array_upper(words, 1) IS NOT NULL THEN
297 FOR j IN 1..array_upper(words, 1) LOOP
298 IF (words[j] != '') THEN
299 w = getorcreate_word_id(words[j]);
300 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
301 result := result || w;
307 words := regexp_split_to_array(item.value, E'[,;()]');
308 IF array_upper(words, 1) != 1 THEN
309 FOR j IN 1..array_upper(words, 1) LOOP
310 s := make_standard_name(words[j]);
312 w := getorcreate_word_id(s);
313 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
314 result := result || w;
320 s := regexp_replace(item.value, '市$', '');
321 IF s != item.value THEN
322 s := make_standard_name(s);
324 w := getorcreate_name_id(s, item.value);
325 IF NOT (ARRAY[w] <@ result) THEN
326 result := result || w;
336 LANGUAGE plpgsql IMMUTABLE;
338 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
348 result := '{}'::INTEGER[];
350 s := make_standard_name(src);
351 w := getorcreate_name_id(s, src);
353 IF NOT (ARRAY[w] <@ result) THEN
354 result := result || w;
357 w := getorcreate_word_id(s);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
363 words := string_to_array(s, ' ');
364 IF array_upper(words, 1) IS NOT NULL THEN
365 FOR j IN 1..array_upper(words, 1) LOOP
366 IF (words[j] != '') THEN
367 w = getorcreate_word_id(words[j]);
368 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
369 result := result || w;
375 words := regexp_split_to_array(src, E'[,;()]');
376 IF array_upper(words, 1) != 1 THEN
377 FOR j IN 1..array_upper(words, 1) LOOP
378 s := make_standard_name(words[j]);
380 w := getorcreate_word_id(s);
381 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
382 result := result || w;
388 s := regexp_replace(src, '市$', '');
390 s := make_standard_name(s);
392 w := getorcreate_name_id(s, src);
393 IF NOT (ARRAY[w] <@ result) THEN
394 result := result || w;
402 LANGUAGE plpgsql IMMUTABLE;
404 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
407 place_centre GEOMETRY;
410 place_centre := ST_PointOnSurface(place);
412 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
414 -- Try for a OSM polygon
415 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
417 RETURN nearcountry.country_code;
420 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
422 -- Try for OSM fallback data
423 -- The order is to deal with places like HongKong that are 'states' within another polygon
424 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
426 RETURN nearcountry.country_code;
429 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
431 -- Natural earth data
432 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
434 RETURN nearcountry.country_code;
437 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
440 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
442 RETURN nearcountry.country_code;
445 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
447 -- Natural earth data
448 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
450 RETURN nearcountry.country_code;
456 LANGUAGE plpgsql IMMUTABLE;
458 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
463 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
465 RETURN lower(nearcountry.country_default_language_code);
470 LANGUAGE plpgsql IMMUTABLE;
472 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
477 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
479 RETURN lower(nearcountry.country_default_language_codes);
484 LANGUAGE plpgsql IMMUTABLE;
486 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
491 FOR nearcountry IN select partition from country_name where country_code = in_country_code
493 RETURN nearcountry.partition;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
504 DELETE FROM location_area where place_id = OLD_place_id;
505 -- TODO:location_area
511 CREATE OR REPLACE FUNCTION add_location(
513 country_code varchar(2),
517 rank_address INTEGER,
532 IF rank_search > 25 THEN
533 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
536 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
538 x := deleteLocationArea(partition, place_id, rank_search);
541 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
544 centroid := ST_Centroid(geometry);
546 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
547 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
553 IF rank_address = 0 THEN
555 ELSEIF rank_search <= 14 THEN
557 ELSEIF rank_search <= 15 THEN
559 ELSEIF rank_search <= 16 THEN
561 ELSEIF rank_search <= 17 THEN
563 ELSEIF rank_search <= 21 THEN
565 ELSEIF rank_search = 25 THEN
569 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
571 secgeo := ST_Buffer(geometry, diameter);
572 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
582 -- find the parent road of the cut road parts
583 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
584 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
589 parent_place_id BIGINT;
590 address_street_word_ids INTEGER[];
596 addr_street = street;
599 IF addr_street is null and addr_place is null THEN
600 select nodes from planet_osm_ways where id = wayid INTO waynodes;
601 FOR location IN SELECT placex.street, placex.addr_place from placex
602 where osm_type = 'N' and osm_id = ANY(waynodes)
603 and (placex.street is not null or placex.addr_place is not null)
604 and indexed_status < 100
606 addr_street = location.street;
607 addr_place = location.addr_place;
611 IF addr_street IS NOT NULL THEN
612 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
613 IF address_street_word_ids IS NOT NULL THEN
614 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
615 parent_place_id := location.place_id;
620 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
621 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
622 IF address_street_word_ids IS NOT NULL THEN
623 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
624 parent_place_id := location.place_id;
629 IF parent_place_id is null THEN
630 FOR location IN SELECT place_id FROM placex
631 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
632 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
633 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
636 parent_place_id := location.place_id;
640 IF parent_place_id is null THEN
644 RETURN parent_place_id;
650 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
653 NEW.place_id := nextval('seq_place');
654 NEW.indexed_date := now();
656 IF NEW.indexed_status IS NULL THEN
657 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
658 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
659 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
663 NEW.indexed_status := 1; --STATUS_NEW
664 NEW.country_code := lower(get_country_code(NEW.linegeo));
666 NEW.partition := get_partition(NEW.country_code);
667 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
676 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
682 country_code VARCHAR(2);
683 default_language VARCHAR(10);
688 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
690 NEW.place_id := nextval('seq_place');
691 NEW.indexed_status := 1; --STATUS_NEW
693 NEW.country_code := lower(get_country_code(NEW.geometry));
695 NEW.partition := get_partition(NEW.country_code);
696 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
698 -- copy 'name' to or from the default language (if there is a default language)
699 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
700 default_language := get_country_language_code(NEW.country_code);
701 IF default_language IS NOT NULL THEN
702 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
703 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
704 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
705 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
710 IF NEW.osm_type = 'X' THEN
711 -- E'X'ternal records should already be in the right format so do nothing
713 NEW.rank_search := 30;
714 NEW.rank_address := NEW.rank_search;
716 -- By doing in postgres we have the country available to us - currently only used for postcode
717 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
719 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
720 -- most likely just a part of a multipolygon postcode boundary, throw it away
724 NEW.postcode := NEW.address->'postcode';
725 NEW.name := hstore('ref', NEW.postcode);
727 IF NEW.country_code = 'gb' THEN
729 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
730 NEW.rank_search := 25;
731 NEW.rank_address := 5;
732 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
733 NEW.rank_search := 23;
734 NEW.rank_address := 5;
735 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
736 NEW.rank_search := 21;
737 NEW.rank_address := 5;
740 ELSEIF NEW.country_code = 'sg' THEN
742 IF NEW.postcode ~ '^([0-9]{6})$' THEN
743 NEW.rank_search := 25;
744 NEW.rank_address := 11;
747 ELSEIF NEW.country_code = 'de' THEN
749 IF NEW.postcode ~ '^([0-9]{5})$' THEN
750 NEW.rank_search := 21;
751 NEW.rank_address := 11;
755 -- Guess at the postcode format and coverage (!)
756 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
757 NEW.rank_search := 21;
758 NEW.rank_address := 11;
760 -- Does it look splitable into and area and local code?
761 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
763 IF postcode IS NOT NULL THEN
764 NEW.rank_search := 25;
765 NEW.rank_address := 11;
766 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
767 NEW.rank_search := 21;
768 NEW.rank_address := 11;
773 ELSEIF NEW.class = 'place' THEN
774 IF NEW.type in ('continent') THEN
775 NEW.rank_search := 2;
776 NEW.rank_address := NEW.rank_search;
777 NEW.country_code := NULL;
778 ELSEIF NEW.type in ('sea') THEN
779 NEW.rank_search := 2;
780 NEW.rank_address := 0;
781 NEW.country_code := NULL;
782 ELSEIF NEW.type in ('country') THEN
783 NEW.rank_search := 4;
784 NEW.rank_address := NEW.rank_search;
785 ELSEIF NEW.type in ('state') THEN
786 NEW.rank_search := 8;
787 NEW.rank_address := NEW.rank_search;
788 ELSEIF NEW.type in ('region') THEN
789 NEW.rank_search := 18; -- dropped from previous value of 10
790 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
791 ELSEIF NEW.type in ('county') THEN
792 NEW.rank_search := 12;
793 NEW.rank_address := NEW.rank_search;
794 ELSEIF NEW.type in ('city') THEN
795 NEW.rank_search := 16;
796 NEW.rank_address := NEW.rank_search;
797 ELSEIF NEW.type in ('island') THEN
798 NEW.rank_search := 17;
799 NEW.rank_address := 0;
800 ELSEIF NEW.type in ('town') THEN
801 NEW.rank_search := 18;
802 NEW.rank_address := 16;
803 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
804 NEW.rank_search := 19;
805 NEW.rank_address := 16;
806 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
807 NEW.rank_search := 20;
808 NEW.rank_address := NEW.rank_search;
809 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
810 NEW.rank_search := 20;
811 NEW.rank_address := 0;
812 -- Irish townlands, tagged as place=locality and locality=townland
813 IF (NEW.extratags -> 'locality') = 'townland' THEN
814 NEW.rank_address := 20;
816 ELSEIF NEW.type in ('neighbourhood') THEN
817 NEW.rank_search := 22;
818 NEW.rank_address := 22;
819 ELSEIF NEW.type in ('house','building') THEN
820 NEW.rank_search := 30;
821 NEW.rank_address := NEW.rank_search;
822 ELSEIF NEW.type in ('houses') THEN
823 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
824 NEW.rank_search := 28;
825 NEW.rank_address := 0;
828 ELSEIF NEW.class = 'boundary' THEN
829 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
830 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
833 NEW.rank_search := NEW.admin_level * 2;
834 IF NEW.type = 'administrative' THEN
835 NEW.rank_address := NEW.rank_search;
837 NEW.rank_address := 0;
839 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
840 NEW.rank_search := 22;
841 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
842 NEW.rank_address := NEW.rank_search;
844 NEW.rank_address := 0;
846 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
847 NEW.rank_search := 18;
848 NEW.rank_address := 0;
849 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
850 NEW.rank_search := 4;
851 NEW.rank_address := NEW.rank_search;
852 -- any feature more than 5 square miles is probably worth indexing
853 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
854 NEW.rank_search := 22;
855 NEW.rank_address := 0;
856 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
858 ELSEIF NEW.class = 'waterway' THEN
859 IF NEW.osm_type = 'R' THEN
860 NEW.rank_search := 16;
862 NEW.rank_search := 17;
864 NEW.rank_address := 0;
865 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
866 NEW.rank_search := 27;
867 NEW.rank_address := NEW.rank_search;
868 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
869 NEW.rank_search := 26;
870 NEW.rank_address := NEW.rank_search;
871 ELSEIF NEW.class = 'mountain_pass' THEN
872 NEW.rank_search := 20;
873 NEW.rank_address := 0;
878 IF NEW.rank_search > 30 THEN
879 NEW.rank_search := 30;
882 IF NEW.rank_address > 30 THEN
883 NEW.rank_address := 30;
886 IF (NEW.extratags -> 'capital') = 'yes' THEN
887 NEW.rank_search := NEW.rank_search - 1;
890 -- a country code make no sense below rank 4 (country)
891 IF NEW.rank_search < 4 THEN
892 NEW.country_code := NULL;
895 -- Block import below rank 22
896 -- IF NEW.rank_search > 22 THEN
900 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
902 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
904 IF NEW.rank_address > 0 THEN
905 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
906 -- Performance: We just can't handle re-indexing for country level changes
907 IF st_area(NEW.geometry) < 1 THEN
908 -- mark items within the geometry for re-indexing
909 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
911 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
912 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
913 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
914 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
915 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
918 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
920 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
921 IF NEW.type='postcode' THEN
923 ELSEIF NEW.rank_search < 16 THEN
925 ELSEIF NEW.rank_search < 18 THEN
927 ELSEIF NEW.rank_search < 20 THEN
929 ELSEIF NEW.rank_search = 21 THEN
931 ELSEIF NEW.rank_search < 24 THEN
933 ELSEIF NEW.rank_search < 26 THEN
934 diameter := 0.002; -- 100 to 200 meters
935 ELSEIF NEW.rank_search < 28 THEN
936 diameter := 0.001; -- 50 to 100 meters
939 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
940 IF NEW.rank_search >= 26 THEN
941 -- roads may cause reparenting for >27 rank places
942 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
943 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
944 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
945 ELSEIF NEW.rank_search >= 16 THEN
946 -- up to rank 16, street-less addresses may need reparenting
947 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
949 -- for all other places the search terms may change as well
950 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);
957 -- add to tables for special search
958 -- Note: won't work on initial import because the classtype tables
959 -- do not yet exist. It won't hurt either.
960 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
961 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
963 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
964 USING NEW.place_id, ST_Centroid(NEW.geometry);
973 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
977 place_centroid GEOMETRY;
995 IF OLD.indexed_status = 100 THEN
996 delete from location_property_osmline where place_id = OLD.place_id;
1000 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1004 -- if the line was newly inserted, split the line as necessary
1005 IF OLD.indexed_status = 1 THEN
1006 NEW.interpolationtype = NEW.address->'interpolation';
1008 IF NEW.address is not NULL THEN
1009 IF NEW.address ? 'street' THEN
1010 NEW.street = NEW.address->'street';
1013 IF NEW.address ? 'place' THEN
1014 NEW.addr_place = NEW.address->'place';
1017 IF NEW.address ? 'postcode' THEN
1018 NEW.addr_place = NEW.address->'postcode';
1022 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1024 IF array_upper(waynodes, 1) IS NULL THEN
1028 linegeo := NEW.linegeo;
1029 startnumber := NULL;
1030 street := NEW.street;
1031 addr_place := NEW.addr_place;
1032 postcode := NEW.postcode;
1034 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1036 select osm_id, address, geometry
1037 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1038 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1039 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1040 IF nextnode.osm_id IS NOT NULL THEN
1041 --RAISE NOTICE 'place_id is not null';
1042 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1043 -- Make sure that the point is actually on the line. That might
1044 -- be a bit paranoid but ensures that the algorithm still works
1045 -- should osm2pgsql attempt to repair geometries.
1046 splitline := split_line_on_node(linegeo, nextnode.geometry);
1047 sectiongeo := ST_GeometryN(splitline, 1);
1048 linegeo := ST_GeometryN(splitline, 2);
1050 sectiongeo = linegeo;
1052 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1054 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1055 AND startnumber != endnumber
1056 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1058 IF (startnumber > endnumber) THEN
1059 housenum := endnumber;
1060 endnumber := startnumber;
1061 startnumber := housenum;
1062 sectiongeo := ST_Reverse(sectiongeo);
1065 seg_street := coalesce(street,
1066 prevnode.address->'street',
1067 nextnode.address->'street');
1068 seg_place := coalesce(addr_place,
1069 prevnode.address->'place',
1070 nextnode.address->'place');
1071 seg_postcode := coalesce(postcode,
1072 prevnode.address->'postcode',
1073 nextnode.address->'postcode');
1075 IF NEW.startnumber IS NULL THEN
1076 NEW.startnumber := startnumber;
1077 NEW.endnumber := endnumber;
1078 NEW.linegeo := sectiongeo;
1079 NEW.street := seg_street;
1080 NEW.addr_place := seg_place;
1081 NEW.postcode := seg_postcode;
1083 insert into location_property_osmline
1084 (linegeo, partition, osm_id, parent_place_id,
1085 startnumber, endnumber, interpolationtype,
1086 address, street, addr_place, postcode, country_code,
1087 geometry_sector, indexed_status)
1088 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1089 startnumber, endnumber, NEW.interpolationtype,
1090 NEW.address, seg_street, seg_place, seg_postcode,
1091 NEW.country_code, NEW.geometry_sector, 0);
1095 -- early break if we are out of line string,
1096 -- might happen when a line string loops back on itself
1097 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1101 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1102 prevnode := nextnode;
1107 place_centroid := ST_PointOnSurface(NEW.linegeo);
1108 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1109 NEW.partition, place_centroid, NEW.linegeo);
1111 -- marking descendants for reparenting is not needed, because there are
1112 -- actually no descendants for interpolation lines
1120 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1125 place_centroid GEOMETRY;
1127 search_maxdistance FLOAT[];
1128 search_mindistance FLOAT[];
1129 address_havelevel BOOLEAN[];
1136 relation_members TEXT[];
1138 linkedplacex RECORD;
1139 search_diameter FLOAT;
1140 search_prevdiameter FLOAT;
1141 search_maxrank INTEGER;
1142 address_maxrank INTEGER;
1143 address_street_word_id INTEGER;
1144 address_street_word_ids INTEGER[];
1145 parent_place_id_rank BIGINT;
1150 location_rank_search INTEGER;
1151 location_distance FLOAT;
1152 location_parent GEOMETRY;
1153 location_isaddress BOOLEAN;
1154 location_keywords INTEGER[];
1156 default_language TEXT;
1157 name_vector INTEGER[];
1158 nameaddress_vector INTEGER[];
1160 linked_node_id BIGINT;
1165 IF OLD.indexed_status = 100 THEN
1166 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1167 delete from placex where place_id = OLD.place_id;
1171 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1175 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1177 --RAISE WARNING '%',NEW.place_id;
1178 --RAISE WARNING '%', NEW;
1180 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1181 -- Silently do nothing
1185 NEW.indexed_date = now();
1187 result := deleteSearchName(NEW.partition, NEW.place_id);
1188 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1189 result := deleteRoad(NEW.partition, NEW.place_id);
1190 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1191 UPDATE placex set linked_place_id = null, indexed_status = 2
1192 where linked_place_id = NEW.place_id;
1193 -- update not necessary for osmline, cause linked_place_id does not exist
1195 IF NEW.linked_place_id is not null THEN
1199 IF NEW.address is not NULL THEN
1200 IF NEW.address ? 'conscriptionnumber' THEN
1201 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1202 IF NEW.address ? 'streetnumber' THEN
1203 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1204 NEW.housenumber := NEW.address->'conscriptionnumber' || '/' || NEW.address->'streetnumber';
1206 NEW.housenumber := NEW.address->'conscriptionnumber';
1208 ELSEIF NEW.address ? 'streetnumber' THEN
1209 NEW.housenumber := NEW.address->'streetnumber';
1210 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1211 ELSEIF NEW.address ? 'housenumber' THEN
1212 NEW.housenumber := NEW.address->'housenumber';
1213 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1216 IF NEW.address ? 'street' THEN
1217 NEW.street = NEW.address->'street';
1220 IF NEW.address ? 'place' THEN
1221 NEW.addr_place = NEW.address->'place';
1224 IF NEW.address ? 'postcode' THEN
1225 NEW.postcode = NEW.address->'postcode';
1229 -- Speed up searches - just use the centroid of the feature
1230 -- cheaper but less acurate
1231 place_centroid := ST_PointOnSurface(NEW.geometry);
1232 NEW.centroid := null;
1234 -- recalculate country and partition
1235 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1236 -- for countries, believe the mapped country code,
1237 -- so that we remain in the right partition if the boundaries
1239 NEW.country_code := lower(NEW.address->'country');
1240 NEW.partition := get_partition(lower(NEW.country_code));
1241 IF NEW.partition = 0 THEN
1242 NEW.country_code := lower(get_country_code(place_centroid));
1243 NEW.partition := get_partition(NEW.country_code);
1246 IF NEW.rank_search >= 4 THEN
1247 NEW.country_code := lower(get_country_code(place_centroid));
1249 NEW.country_code := NULL;
1251 NEW.partition := get_partition(NEW.country_code);
1254 -- waterway ways are linked when they are part of a relation and have the same class/type
1255 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1256 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1258 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1259 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1260 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1261 FOR linked_node_id IN SELECT place_id FROM placex
1262 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1263 and class = NEW.class and type = NEW.type
1264 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1266 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1273 -- Adding ourselves to the list simplifies address calculations later
1274 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1276 -- What level are we searching from
1277 search_maxrank := NEW.rank_search;
1279 -- Thought this wasn't needed but when we add new languages to the country_name table
1280 -- we need to update the existing names
1281 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1282 default_language := get_country_language_code(NEW.country_code);
1283 IF default_language IS NOT NULL THEN
1284 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1285 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1286 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1287 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1292 -- Initialise the name vector using our name
1293 name_vector := make_keywords(NEW.name);
1294 nameaddress_vector := '{}'::int[];
1297 address_havelevel[i] := false;
1300 NEW.importance := null;
1301 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1302 IF NEW.importance IS NULL THEN
1303 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;
1306 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1308 -- ---------------------------------------------------------------------------
1309 -- For low level elements we inherit from our parent road
1310 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1312 --RAISE WARNING 'finding street for %', NEW;
1314 -- We won't get a better centroid, besides these places are too small to care
1315 NEW.centroid := place_centroid;
1317 NEW.parent_place_id := null;
1319 -- if we have a POI and there is no address information,
1320 -- see if we can get it from a surrounding building
1321 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1322 AND NEW.housenumber IS NULL THEN
1323 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1324 and (housenumber is not null or street is not null or addr_place is not null)
1325 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1328 NEW.housenumber := location.housenumber;
1329 NEW.street := location.street;
1330 NEW.addr_place := location.addr_place;
1334 -- We have to find our parent road.
1335 -- Copy data from linked items (points on ways, addr:street links, relations)
1337 -- Is this object part of a relation?
1338 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1340 -- At the moment we only process one type of relation - associatedStreet
1341 IF relation.tags @> ARRAY['associatedStreet'] THEN
1342 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1343 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1344 --RAISE WARNING 'node in relation %',relation;
1345 SELECT place_id from placex where osm_type = 'W'
1346 and osm_id = substring(relation.members[i],2,200)::bigint
1347 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1354 -- Note that addr:street links can only be indexed once the street itself is indexed
1355 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1356 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1357 IF address_street_word_ids IS NOT NULL THEN
1358 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1359 NEW.parent_place_id := location.place_id;
1364 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1365 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1366 IF address_street_word_ids IS NOT NULL THEN
1367 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1368 NEW.parent_place_id := location.place_id;
1373 -- Is this node part of an interpolation?
1374 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1376 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1377 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1380 NEW.parent_place_id := location.parent_place_id;
1384 -- Is this node part of a way?
1385 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1387 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w
1388 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)
1391 -- Way IS a road then we are on it - that must be our road
1392 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1393 --RAISE WARNING 'node in way that is a street %',location;
1394 NEW.parent_place_id := location.place_id;
1397 -- If the way mentions a street or place address, try that for parenting.
1398 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1399 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1400 IF address_street_word_ids IS NOT NULL THEN
1401 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1402 NEW.parent_place_id := linkedplacex.place_id;
1407 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1408 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1409 IF address_street_word_ids IS NOT NULL THEN
1410 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1411 NEW.parent_place_id := linkedplacex.place_id;
1416 -- Is the WAY part of a relation
1417 IF NEW.parent_place_id IS NULL THEN
1418 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1420 -- At the moment we only process one type of relation - associatedStreet
1421 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1422 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1423 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1424 --RAISE WARNING 'node in way that is in a relation %',relation;
1425 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1426 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1437 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1438 -- Still nothing, just use the nearest road
1439 IF NEW.parent_place_id IS NULL THEN
1440 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1441 NEW.parent_place_id := location.place_id;
1446 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1448 -- If we didn't find any road fallback to standard method
1449 IF NEW.parent_place_id IS NOT NULL THEN
1451 -- Get the details of the parent road
1452 select * from search_name where place_id = NEW.parent_place_id INTO location;
1453 NEW.country_code := location.country_code;
1455 -- Merge the postcode into the parent's address if necessary
1456 IF NEW.postcode IS NOT NULL THEN
1457 isin_tokens := '{}'::int[];
1458 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1459 IF address_street_word_id is not null
1460 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1461 isin_tokens := isin_tokens || address_street_word_id;
1463 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1464 IF address_street_word_id is not null
1465 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1466 isin_tokens := isin_tokens || address_street_word_id;
1468 IF isin_tokens != '{}'::int[] THEN
1470 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1471 WHERE place_id = NEW.parent_place_id;
1475 --RAISE WARNING '%', NEW.name;
1476 -- If there is no name it isn't searchable, don't bother to create a search record
1477 IF NEW.name is NULL THEN
1481 -- Merge address from parent
1482 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1483 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1485 -- Performance, it would be more acurate to do all the rest of the import
1486 -- process but it takes too long
1487 -- Just be happy with inheriting from parent road only
1489 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1490 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1493 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);
1500 -- RAISE WARNING ' INDEXING Started:';
1501 -- RAISE WARNING ' INDEXING: %',NEW;
1503 -- ---------------------------------------------------------------------------
1506 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1508 -- see if we have any special relation members
1509 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1511 -- RAISE WARNING 'get_osm_rel_members, label';
1512 IF relation_members IS NOT NULL THEN
1513 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1515 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1516 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1518 -- If we don't already have one use this as the centre point of the geometry
1519 IF NEW.centroid IS NULL THEN
1520 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1523 -- merge in the label name, re-init word vector
1524 IF NOT linkedPlacex.name IS NULL THEN
1525 NEW.name := linkedPlacex.name || NEW.name;
1526 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1529 -- merge in extra tags
1530 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1532 -- mark the linked place (excludes from search results)
1533 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1535 -- keep a note of the node id in case we need it for wikipedia in a bit
1536 linked_node_id := linkedPlacex.osm_id;
1541 IF NEW.centroid IS NULL THEN
1543 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1545 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1546 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1548 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1549 -- But that can be fixed by explicitly setting the label in the data
1550 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1551 AND NEW.rank_address = linkedPlacex.rank_address THEN
1553 -- If we don't already have one use this as the centre point of the geometry
1554 IF NEW.centroid IS NULL THEN
1555 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1558 -- merge in the name, re-init word vector
1559 IF NOT linkedPlacex.name IS NULL THEN
1560 NEW.name := linkedPlacex.name || NEW.name;
1561 name_vector := make_keywords(NEW.name);
1564 -- merge in extra tags
1565 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1567 -- mark the linked place (excludes from search results)
1568 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1570 -- keep a note of the node id in case we need it for wikipedia in a bit
1571 linked_node_id := linkedPlacex.osm_id;
1583 -- Name searches can be done for ways as well as relations
1584 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1586 -- not found one yet? how about doing a name search
1587 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1589 FOR linkedPlacex IN select placex.* from placex WHERE
1590 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1591 AND placex.rank_address = NEW.rank_address
1592 AND placex.place_id != NEW.place_id
1593 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1594 AND st_covers(NEW.geometry, placex.geometry)
1597 -- If we don't already have one use this as the centre point of the geometry
1598 IF NEW.centroid IS NULL THEN
1599 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1602 -- merge in the name, re-init word vector
1603 NEW.name := linkedPlacex.name || NEW.name;
1604 name_vector := make_keywords(NEW.name);
1606 -- merge in extra tags
1607 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1609 -- mark the linked place (excludes from search results)
1610 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1612 -- keep a note of the node id in case we need it for wikipedia in a bit
1613 linked_node_id := linkedPlacex.osm_id;
1617 IF NEW.centroid IS NOT NULL THEN
1618 place_centroid := NEW.centroid;
1619 -- Place might have had only a name tag before but has now received translations
1620 -- from the linked place. Make sure a name tag for the default language exists in
1622 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1623 default_language := get_country_language_code(NEW.country_code);
1624 IF default_language IS NOT NULL THEN
1625 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1626 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1627 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1628 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1634 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1635 IF NEW.importance is null THEN
1636 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1638 -- Still null? how about looking it up by the node id
1639 IF NEW.importance IS NULL THEN
1640 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;
1645 -- make sure all names are in the word table
1646 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1647 perform create_country(NEW.name, lower(NEW.country_code));
1650 NEW.parent_place_id = 0;
1651 parent_place_id_rank = 0;
1654 -- convert isin to array of tokenids
1655 isin_tokens := '{}'::int[];
1656 IF NEW.address IS NOT NULL THEN
1657 isin := avals(NEW.address);
1658 IF array_upper(isin, 1) IS NOT NULL THEN
1659 FOR i IN 1..array_upper(isin, 1) LOOP
1660 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1661 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1662 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1663 isin_tokens := isin_tokens || address_street_word_id;
1666 -- merge word into address vector
1667 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1668 IF address_street_word_id IS NOT NULL THEN
1669 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1674 IF NEW.postcode IS NOT NULL THEN
1675 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1676 IF array_upper(isin, 1) IS NOT NULL THEN
1677 FOR i IN 1..array_upper(isin, 1) LOOP
1678 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1679 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1680 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1681 isin_tokens := isin_tokens || address_street_word_id;
1684 -- merge into address vector
1685 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1686 IF address_street_word_id IS NOT NULL THEN
1687 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1693 -- %NOTIGERDATA% IF 0 THEN
1694 -- for the USA we have an additional address table. Merge in zip codes from there too
1695 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1696 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1697 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1698 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1699 isin_tokens := isin_tokens || address_street_word_id;
1701 -- also merge in the single word version
1702 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1703 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1706 -- %NOTIGERDATA% END IF;
1708 -- RAISE WARNING 'ISIN: %', isin_tokens;
1710 -- Process area matches
1711 location_rank_search := 0;
1712 location_distance := 0;
1713 location_parent := NULL;
1714 -- added ourself as address already
1715 address_havelevel[NEW.rank_address] := true;
1716 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1718 SELECT * from getNearFeatures(NEW.partition,
1719 CASE WHEN NEW.rank_search >= 26 THEN NEW.geometry
1720 ELSE place_centroid END,
1721 search_maxrank, isin_tokens)
1724 --RAISE WARNING ' AREA: %',location;
1726 IF location.rank_address != location_rank_search THEN
1727 location_rank_search := location.rank_address;
1728 IF location.isguess THEN
1729 location_distance := location.distance * 1.5;
1731 IF location.rank_address <= 12 THEN
1732 -- for county and above, if we have an area consider that exact
1733 -- (It would be nice to relax the constraint for places close to
1734 -- the boundary but we'd need the exact geometry for that. Too
1736 location_distance = 0;
1738 -- Below county level remain slightly fuzzy.
1739 location_distance := location.distance * 0.5;
1743 CONTINUE WHEN location.keywords <@ location_keywords;
1746 IF location.distance < location_distance OR NOT location.isguess THEN
1747 location_keywords := location.keywords;
1749 location_isaddress := NOT address_havelevel[location.rank_address];
1750 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1751 location_isaddress := ST_Contains(location_parent,location.centroid);
1754 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1755 -- Add it to the list of search terms
1756 IF location.rank_search > 4 THEN
1757 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1759 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1761 IF location_isaddress THEN
1763 address_havelevel[location.rank_address] := true;
1764 IF NOT location.isguess THEN
1765 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1768 IF location.rank_address > parent_place_id_rank THEN
1769 NEW.parent_place_id = location.place_id;
1770 parent_place_id_rank = location.rank_address;
1775 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1781 -- try using the isin value to find parent places
1782 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1783 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1784 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1785 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1787 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1789 --RAISE WARNING ' ISIN: %',location;
1791 IF location.rank_search > 4 THEN
1792 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1793 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1794 address_havelevel[location.rank_address] := true;
1796 IF location.rank_address > parent_place_id_rank THEN
1797 NEW.parent_place_id = location.place_id;
1798 parent_place_id_rank = location.rank_address;
1808 -- for long ways we should add search terms for the entire length
1809 IF st_length(NEW.geometry) > 0.05 THEN
1811 location_rank_search := 0;
1812 location_distance := 0;
1814 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1816 IF location.rank_address != location_rank_search THEN
1817 location_rank_search := location.rank_address;
1818 location_distance := location.distance * 1.5;
1821 IF location.rank_search > 4 AND location.distance < location_distance THEN
1823 -- Add it to the list of search terms
1824 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1825 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1833 -- if we have a name add this to the name search table
1834 IF NEW.name IS NOT NULL THEN
1836 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1837 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1840 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1841 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1844 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);
1848 -- If we've not managed to pick up a better one - default centroid
1849 IF NEW.centroid IS NULL THEN
1850 NEW.centroid := place_centroid;
1858 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1864 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1866 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1867 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1868 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1869 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1871 IF OLD.rank_address < 30 THEN
1873 -- mark everything linked to this place for re-indexing
1874 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1875 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1876 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1878 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1879 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1881 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1882 b := deleteRoad(OLD.partition, OLD.place_id);
1884 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1885 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1886 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1887 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1888 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1892 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1894 IF OLD.rank_address < 26 THEN
1895 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1898 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1900 IF OLD.name is not null THEN
1901 b := deleteSearchName(OLD.partition, OLD.place_id);
1904 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1906 DELETE FROM place_addressline where place_id = OLD.place_id;
1908 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1910 -- remove from tables for special search
1911 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1912 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1914 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1917 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1925 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1931 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1933 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1934 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1935 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;
1937 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1943 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;
1945 -- interpolations are special
1946 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1947 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1956 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1961 existingplacex RECORD;
1962 existingline RECORD;
1963 existinggeometry GEOMETRY;
1964 existingplace_id BIGINT;
1969 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1970 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1971 -- filter wrong tupels
1972 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
1973 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type,
1974 NEW.name, NEW.address->'country',
1975 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1976 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1980 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
1981 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1982 -- Have we already done this place?
1983 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;
1985 -- Get the existing place_id
1986 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1988 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1989 IF existing.osm_type IS NULL THEN
1990 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1993 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1994 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1996 -- 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)
1997 IF existingline.osm_id IS NOT NULL THEN
1998 delete from location_property_osmline where osm_id = NEW.osm_id;
2001 -- for interpolations invalidate all nodes on the line
2002 update placex p set indexed_status = 2
2003 from planet_osm_ways w
2004 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2007 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2008 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2011 IF existing.osm_type IS NULL THEN
2015 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2016 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2017 OR existing.geometry::text != NEW.geometry::text
2022 address = NEW.address,
2023 extratags = NEW.extratags,
2024 admin_level = NEW.admin_level,
2025 geometry = NEW.geometry
2026 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2031 ELSE -- insert to placex
2033 -- Patch in additional country names
2034 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2035 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2036 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2037 IF existing.name IS NOT NULL THEN
2038 NEW.name = existing.name || NEW.name;
2042 -- Have we already done this place?
2043 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;
2045 -- Get the existing place_id
2046 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;
2048 -- Handle a place changing type by removing the old data
2049 -- My generated 'place' types are causing havok because they overlap with real keys
2050 -- TODO: move them to their own special purpose key/class to avoid collisions
2051 IF existing.osm_type IS NULL THEN
2052 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2055 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2056 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2059 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2060 AND st_area(existing.geometry) > 0.02
2061 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2062 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2064 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2065 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2069 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2070 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2072 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2073 IF existingplacex.osm_type IS NULL OR
2074 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2077 IF existingplacex.osm_type IS NOT NULL THEN
2078 -- sanity check: ignore admin_level changes on places with too many active children
2079 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2080 --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;
2081 --LIMIT INDEXING: IF i > 100000 THEN
2082 --LIMIT INDEXING: RETURN null;
2083 --LIMIT INDEXING: END IF;
2086 IF existing.osm_type IS NOT NULL THEN
2087 -- pathological case caused by the triggerless copy into place during initial import
2088 -- force delete even for large areas, it will be reinserted later
2089 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;
2090 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2093 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2094 insert into placex (osm_type, osm_id, class, type, name,
2095 admin_level, address, extratags, geometry)
2096 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2097 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2099 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2104 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2105 IF existing.geometry::text != NEW.geometry::text
2106 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2107 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2110 -- Get the version of the geometry actually used (in placex table)
2111 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;
2113 -- Performance limit
2114 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2116 -- 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
2117 update placex set indexed_status = 2 where indexed_status = 0 and
2118 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2119 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2120 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2122 update placex set indexed_status = 2 where indexed_status = 0 and
2123 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2124 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2125 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2132 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2133 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2134 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2135 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2136 OR existing.geometry::text != NEW.geometry::text
2141 address = NEW.address,
2142 extratags = NEW.extratags,
2143 admin_level = NEW.admin_level,
2144 geometry = NEW.geometry
2145 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2148 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2149 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2150 -- postcode was deleted, no longer retain in placex
2151 DELETE FROM placex where place_id = existingplacex.place_id;
2155 NEW.name := hstore('ref', NEW.address->'postcode');
2160 address = NEW.address,
2161 parent_place_id = null,
2162 extratags = NEW.extratags,
2163 admin_level = NEW.admin_level,
2165 geometry = NEW.geometry
2166 where place_id = existingplacex.place_id;
2168 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2169 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2170 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2171 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2172 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);
2177 -- Abort the add (we modified the existing place instead)
2182 $$ LANGUAGE plpgsql;
2185 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2190 IF name is null THEN
2194 FOR j IN 1..array_upper(languagepref,1) LOOP
2195 IF name ? languagepref[j] THEN
2196 result := trim(name->languagepref[j]);
2197 IF result != '' THEN
2203 -- anything will do as a fallback - just take the first name type thing there is
2204 RETURN trim((avals(name))[1]);
2207 LANGUAGE plpgsql IMMUTABLE;
2210 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2221 search := ARRAY['ref'];
2224 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2227 select rank_address,name,distance,length(name::text) as namelength
2228 from place_addressline join placex on (address_place_id = placex.place_id)
2229 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2230 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2232 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2233 FOR j IN 1..array_upper(search, 1) LOOP
2234 FOR k IN 1..array_upper(location.name, 1) LOOP
2235 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
2236 result[(100 - location.rank_address)] := trim(location.name[k].value);
2237 found := location.rank_address;
2244 RETURN array_to_string(result,', ');
2249 --housenumber only needed for tiger data
2250 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2262 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2263 currresult := trim(get_name_by_language(location.name, languagepref));
2264 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2265 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2266 prevresult := currresult;
2270 RETURN array_to_string(result,', ');
2275 DROP TYPE IF EXISTS addressline CASCADE;
2276 create type addressline as (
2283 admin_level INTEGER,
2286 rank_address INTEGER,
2290 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2293 for_place_id BIGINT;
2298 countrylocation RECORD;
2299 searchcountrycode varchar(2);
2300 searchhousenumber TEXT;
2301 searchhousename HSTORE;
2302 searchrankaddress INTEGER;
2303 searchpostcode TEXT;
2309 -- first query osmline (interpolation lines)
2310 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2311 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2312 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2313 IF for_place_id IS NOT NULL THEN
2314 searchhousenumber = in_housenumber::text;
2317 --then query tiger data
2318 -- %NOTIGERDATA% IF 0 THEN
2319 IF for_place_id IS NULL THEN
2320 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2321 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2322 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2323 IF for_place_id IS NOT NULL THEN
2324 searchhousenumber = in_housenumber::text;
2327 -- %NOTIGERDATA% END IF;
2329 -- %NOAUXDATA% IF 0 THEN
2330 IF for_place_id IS NULL THEN
2331 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2332 WHERE place_id = in_place_id
2333 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2335 -- %NOAUXDATA% END IF;
2337 IF for_place_id IS NULL THEN
2338 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2339 WHERE place_id = in_place_id and rank_search > 27
2340 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2343 IF for_place_id IS NULL THEN
2344 select coalesce(linked_place_id, place_id), country_code,
2345 housenumber, rank_search, postcode, null
2346 from placex where place_id = in_place_id
2347 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2350 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2353 hadcountry := false;
2355 select placex.place_id, osm_type, osm_id,
2356 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2357 class, type, admin_level, true as fromarea, true as isaddress,
2358 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2359 0 as distance, country_code, postcode
2361 where place_id = for_place_id
2363 --RAISE WARNING '%',location;
2364 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2365 searchcountrycode := location.country_code;
2367 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2368 location.isaddress := FALSE;
2370 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2371 searchpostcode := location.postcode;
2373 IF location.rank_address = 4 AND location.isaddress THEN
2376 IF location.rank_address < 4 AND NOT hadcountry THEN
2377 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2378 IF countryname IS NOT NULL THEN
2379 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2380 RETURN NEXT countrylocation;
2383 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2384 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2385 location.distance)::addressline;
2386 RETURN NEXT countrylocation;
2387 found := location.rank_address;
2391 select placex.place_id, osm_type, osm_id,
2392 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2393 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2394 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2395 admin_level, fromarea, isaddress,
2396 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,
2397 distance,country_code,postcode
2398 from place_addressline join placex on (address_place_id = placex.place_id)
2399 where place_addressline.place_id = for_place_id
2400 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2401 and address_place_id != for_place_id
2402 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2403 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2405 --RAISE WARNING '%',location;
2406 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2407 searchcountrycode := location.country_code;
2409 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2410 location.isaddress := FALSE;
2412 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2413 searchpostcode := location.postcode;
2415 IF location.rank_address = 4 AND location.isaddress THEN
2418 IF location.rank_address < 4 AND NOT hadcountry THEN
2419 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2420 IF countryname IS NOT NULL THEN
2421 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2422 RETURN NEXT countrylocation;
2425 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2426 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2427 location.distance)::addressline;
2428 RETURN NEXT countrylocation;
2429 found := location.rank_address;
2433 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2434 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2435 IF countryname IS NOT NULL THEN
2436 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2437 RETURN NEXT location;
2441 IF searchcountrycode IS NOT NULL THEN
2442 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2443 RETURN NEXT location;
2446 IF searchhousename IS NOT NULL THEN
2447 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2448 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2449 RETURN NEXT location;
2452 IF searchhousenumber IS NOT NULL THEN
2453 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2454 RETURN NEXT location;
2457 IF searchpostcode IS NOT NULL THEN
2458 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2459 RETURN NEXT location;
2468 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2474 ELSEIF rank < 4 THEN
2476 ELSEIF rank < 8 THEN
2478 ELSEIF rank < 12 THEN
2480 ELSEIF rank < 16 THEN
2482 ELSEIF rank = 16 THEN
2484 ELSEIF rank = 17 THEN
2485 RETURN 'Town / Island';
2486 ELSEIF rank = 18 THEN
2487 RETURN 'Village / Hamlet';
2488 ELSEIF rank = 20 THEN
2490 ELSEIF rank = 21 THEN
2491 RETURN 'Postcode Area';
2492 ELSEIF rank = 22 THEN
2493 RETURN 'Croft / Farm / Locality / Islet';
2494 ELSEIF rank = 23 THEN
2495 RETURN 'Postcode Area';
2496 ELSEIF rank = 25 THEN
2497 RETURN 'Postcode Point';
2498 ELSEIF rank = 26 THEN
2499 RETURN 'Street / Major Landmark';
2500 ELSEIF rank = 27 THEN
2501 RETURN 'Minory Street / Path';
2502 ELSEIF rank = 28 THEN
2503 RETURN 'House / Building';
2505 RETURN 'Other: '||rank;
2512 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2518 ELSEIF rank < 2 THEN
2520 ELSEIF rank < 4 THEN
2522 ELSEIF rank = 5 THEN
2524 ELSEIF rank < 8 THEN
2526 ELSEIF rank < 12 THEN
2528 ELSEIF rank < 16 THEN
2530 ELSEIF rank = 16 THEN
2532 ELSEIF rank = 17 THEN
2533 RETURN 'Town / Village / Hamlet';
2534 ELSEIF rank = 20 THEN
2536 ELSEIF rank = 21 THEN
2537 RETURN 'Postcode Area';
2538 ELSEIF rank = 22 THEN
2539 RETURN 'Croft / Farm / Locality / Islet';
2540 ELSEIF rank = 23 THEN
2541 RETURN 'Postcode Area';
2542 ELSEIF rank = 25 THEN
2543 RETURN 'Postcode Point';
2544 ELSEIF rank = 26 THEN
2545 RETURN 'Street / Major Landmark';
2546 ELSEIF rank = 27 THEN
2547 RETURN 'Minory Street / Path';
2548 ELSEIF rank = 28 THEN
2549 RETURN 'House / Building';
2551 RETURN 'Other: '||rank;
2558 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2559 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2564 place_centroid GEOMETRY;
2565 out_partition INTEGER;
2566 out_parent_place_id BIGINT;
2568 address_street_word_id INTEGER;
2573 place_centroid := ST_Centroid(pointgeo);
2574 out_partition := get_partition(in_countrycode);
2575 out_parent_place_id := null;
2577 address_street_word_id := get_name_id(make_standard_name(in_street));
2578 IF address_street_word_id IS NOT NULL THEN
2579 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2580 out_parent_place_id := location.place_id;
2584 IF out_parent_place_id IS NULL THEN
2585 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2586 out_parent_place_id := location.place_id;
2590 out_postcode := in_postcode;
2591 IF out_postcode IS NULL THEN
2592 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2594 IF out_postcode IS NULL THEN
2595 out_postcode := getNearestPostcode(out_partition, place_centroid);
2599 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2600 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2601 newpoints := newpoints + 1;
2608 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2615 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2616 IF members[i+1] = member THEN
2617 result := result || members[i];
2626 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2632 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2633 IF members[i+1] = ANY(memberLabels) THEN
2634 RETURN NEXT members[i];
2643 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2644 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2646 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2647 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
2648 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2649 ), '') AS bytea), 'UTF8');
2651 LANGUAGE SQL IMMUTABLE STRICT;
2653 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2657 RETURN decode_url_part(p);
2659 WHEN others THEN return null;
2662 LANGUAGE plpgsql IMMUTABLE;
2664 DROP TYPE wikipedia_article_match CASCADE;
2665 create type wikipedia_article_match as (
2671 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2677 wiki_article_title TEXT;
2678 wiki_article_language TEXT;
2679 result wikipedia_article_match;
2681 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'];
2683 WHILE langs[i] IS NOT NULL LOOP
2684 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2685 IF wiki_article is not null THEN
2686 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2687 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2688 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2689 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2690 wiki_article := replace(wiki_article,' ','_');
2691 IF strpos(wiki_article, ':') IN (3,4) THEN
2692 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2693 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2695 wiki_article_title := trim(wiki_article);
2696 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;
2699 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2700 from wikipedia_article
2701 where language = wiki_article_language and
2702 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2704 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2705 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2706 where wikipedia_redirect.language = wiki_article_language and
2707 (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'\\',''))
2708 order by importance desc limit 1 INTO result;
2710 IF result.language is not null THEN
2721 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2722 RETURNS SETOF GEOMETRY
2736 remainingdepth INTEGER;
2741 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2743 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2744 RETURN NEXT geometry;
2748 remainingdepth := maxdepth - 1;
2749 area := ST_AREA(geometry);
2750 IF remainingdepth < 1 OR area < maxarea THEN
2751 RETURN NEXT geometry;
2755 xmin := st_xmin(geometry);
2756 xmax := st_xmax(geometry);
2757 ymin := st_ymin(geometry);
2758 ymax := st_ymax(geometry);
2759 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2761 -- if the geometry completely covers the box don't bother to slice any more
2762 IF ST_AREA(secbox) = area THEN
2763 RETURN NEXT geometry;
2767 xmid := (xmin+xmax)/2;
2768 ymid := (ymin+ymax)/2;
2771 FOR seg IN 1..4 LOOP
2774 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2777 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2780 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2783 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2786 IF st_intersects(geometry, secbox) THEN
2787 secgeo := st_intersection(geometry, secbox);
2788 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2789 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2790 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2792 RETURN NEXT geo.geom;
2804 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2805 RETURNS SETOF GEOMETRY
2810 -- 10000000000 is ~~ 1x1 degree
2811 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2812 RETURN NEXT geo.geom;
2820 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2824 osmtype character(1);
2828 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2829 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2830 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2831 -- force delete from place/placex by making it a very small geometry
2832 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;
2833 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2840 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2848 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2849 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2850 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2851 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2852 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2853 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2854 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
2855 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2856 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
2862 ELSEIF rank < 18 THEN
2864 ELSEIF rank < 20 THEN
2866 ELSEIF rank = 21 THEN
2868 ELSEIF rank < 24 THEN
2870 ELSEIF rank < 26 THEN
2871 diameter := 0.002; -- 100 to 200 meters
2872 ELSEIF rank < 28 THEN
2873 diameter := 0.001; -- 50 to 100 meters
2875 IF diameter > 0 THEN
2877 -- roads may cause reparenting for >27 rank places
2878 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2879 ELSEIF rank >= 16 THEN
2880 -- up to rank 16, street-less addresses may need reparenting
2881 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
2883 -- for all other places the search terms may change as well
2884 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);