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 insert_osmline(wayid BIGINT, interpolationtype TEXT,
651 street TEXT, addr_place TEXT,
652 defpostalcode TEXT, country_code TEXT,
654 RETURNS INTEGER AS $$
669 place_centroid GEOMETRY;
670 calculated_country_code VARCHAR(2);
672 geometry_sector INTEGER;
675 place_centroid := ST_PointOnSurface(geom);
676 calculated_country_code := lower(get_country_code(place_centroid));
677 partition := get_partition(calculated_country_code);
678 geometry_sector := geometry_sector(partition, place_centroid);
680 IF interpolationtype != 'odd' AND interpolationtype != 'even' AND interpolationtype!='all' THEN
681 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
685 select nodes from planet_osm_ways where id = wayid INTO waynodes;
687 IF array_upper(waynodes, 1) IS NULL THEN
694 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
696 select * from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
697 and housenumber is not NULL limit 1 INTO nextnode;
698 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
699 IF nextnode.osm_id IS NOT NULL THEN
700 --RAISE NOTICE 'place_id is not null';
701 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
702 -- Make sure that the point is actually on the line. That might
703 -- be a bit paranoid but ensures that the algorithm still works
704 -- should osm2pgsql attempt to repair geometries.
705 splitline := split_line_on_node(linegeo, nextnode.geometry);
706 sectiongeo := ST_GeometryN(splitline, 1);
707 linegeo := ST_GeometryN(splitline, 2);
709 sectiongeo = linegeo;
711 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
713 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
714 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
715 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
717 IF (startnumber > endnumber) THEN
718 housenum := endnumber;
719 endnumber := startnumber;
720 startnumber := housenum;
721 sectiongeo := ST_Reverse(sectiongeo);
724 insert into location_property_osmline
725 values (sectiongeo, nextval('seq_place'), partition, wayid, NULL, startnumber, endnumber,
726 interpolationtype, street, coalesce(prevnode.postcode, defpostalcode),
727 calculated_country_code, geometry_sector, 2, now());
730 -- early break if we are out of line string,
731 -- might happen when a line string loops back on itself
732 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
736 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
737 prevnode := nextnode;
747 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
753 country_code VARCHAR(2);
754 default_language VARCHAR(10);
759 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
761 -- ignore interpolated addresses, not necessary anymore, cause interpolated addresses are now in location_property_osmline
762 IF NEW.class = 'place' and NEW.type = 'address' THEN
766 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
767 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
768 RAISE WARNING 'invalid geometry %',NEW.osm_id;
772 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
774 NEW.place_id := nextval('seq_place');
775 NEW.indexed_status := 1; --STATUS_NEW
777 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
779 NEW.partition := get_partition(NEW.calculated_country_code);
780 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
782 -- copy 'name' to or from the default language (if there is a default language)
783 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
784 default_language := get_country_language_code(NEW.calculated_country_code);
785 IF default_language IS NOT NULL THEN
786 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
787 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
788 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
789 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
794 IF NEW.admin_level > 15 THEN
795 NEW.admin_level := 15;
798 IF NEW.housenumber IS NOT NULL THEN
799 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
802 IF NEW.osm_type = 'X' THEN
803 -- E'X'ternal records should already be in the right format so do nothing
805 NEW.rank_search := 30;
806 NEW.rank_address := NEW.rank_search;
808 -- By doing in postgres we have the country available to us - currently only used for postcode
809 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
811 IF NEW.postcode IS NULL THEN
812 -- most likely just a part of a multipolygon postcode boundary, throw it away
816 NEW.name := hstore('ref', NEW.postcode);
818 IF NEW.calculated_country_code = 'gb' THEN
820 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
821 NEW.rank_search := 25;
822 NEW.rank_address := 5;
823 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
824 NEW.rank_search := 23;
825 NEW.rank_address := 5;
826 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
827 NEW.rank_search := 21;
828 NEW.rank_address := 5;
831 ELSEIF NEW.calculated_country_code = 'sg' THEN
833 IF NEW.postcode ~ '^([0-9]{6})$' THEN
834 NEW.rank_search := 25;
835 NEW.rank_address := 11;
838 ELSEIF NEW.calculated_country_code = 'de' THEN
840 IF NEW.postcode ~ '^([0-9]{5})$' THEN
841 NEW.rank_search := 21;
842 NEW.rank_address := 11;
846 -- Guess at the postcode format and coverage (!)
847 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
848 NEW.rank_search := 21;
849 NEW.rank_address := 11;
851 -- Does it look splitable into and area and local code?
852 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
854 IF postcode IS NOT NULL THEN
855 NEW.rank_search := 25;
856 NEW.rank_address := 11;
857 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
858 NEW.rank_search := 21;
859 NEW.rank_address := 11;
864 ELSEIF NEW.class = 'place' THEN
865 IF NEW.type in ('continent') THEN
866 NEW.rank_search := 2;
867 NEW.rank_address := NEW.rank_search;
868 NEW.calculated_country_code := NULL;
869 ELSEIF NEW.type in ('sea') THEN
870 NEW.rank_search := 2;
871 NEW.rank_address := 0;
872 NEW.calculated_country_code := NULL;
873 ELSEIF NEW.type in ('country') THEN
874 NEW.rank_search := 4;
875 NEW.rank_address := NEW.rank_search;
876 ELSEIF NEW.type in ('state') THEN
877 NEW.rank_search := 8;
878 NEW.rank_address := NEW.rank_search;
879 ELSEIF NEW.type in ('region') THEN
880 NEW.rank_search := 18; -- dropped from previous value of 10
881 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
882 ELSEIF NEW.type in ('county') THEN
883 NEW.rank_search := 12;
884 NEW.rank_address := NEW.rank_search;
885 ELSEIF NEW.type in ('city') THEN
886 NEW.rank_search := 16;
887 NEW.rank_address := NEW.rank_search;
888 ELSEIF NEW.type in ('island') THEN
889 NEW.rank_search := 17;
890 NEW.rank_address := 0;
891 ELSEIF NEW.type in ('town') THEN
892 NEW.rank_search := 18;
893 NEW.rank_address := 16;
894 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
895 NEW.rank_search := 19;
896 NEW.rank_address := 16;
897 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
898 NEW.rank_search := 20;
899 NEW.rank_address := NEW.rank_search;
900 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
901 NEW.rank_search := 20;
902 NEW.rank_address := 0;
903 -- Irish townlands, tagged as place=locality and locality=townland
904 IF (NEW.extratags -> 'locality') = 'townland' THEN
905 NEW.rank_address := 20;
907 ELSEIF NEW.type in ('neighbourhood') THEN
908 NEW.rank_search := 22;
909 NEW.rank_address := 22;
910 ELSEIF NEW.type in ('house','building') THEN
911 NEW.rank_search := 30;
912 NEW.rank_address := NEW.rank_search;
913 ELSEIF NEW.type in ('houses') THEN
914 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
915 NEW.rank_search := 28;
916 NEW.rank_address := 0;
919 ELSEIF NEW.class = 'boundary' THEN
920 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
921 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
924 NEW.rank_search := NEW.admin_level * 2;
925 IF NEW.type = 'administrative' THEN
926 NEW.rank_address := NEW.rank_search;
928 NEW.rank_address := 0;
930 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
931 NEW.rank_search := 22;
932 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
933 NEW.rank_address := NEW.rank_search;
935 NEW.rank_address := 0;
937 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
938 NEW.rank_search := 18;
939 NEW.rank_address := 0;
940 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
941 NEW.rank_search := 4;
942 NEW.rank_address := NEW.rank_search;
943 -- any feature more than 5 square miles is probably worth indexing
944 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
945 NEW.rank_search := 22;
946 NEW.rank_address := 0;
947 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
949 ELSEIF NEW.class = 'waterway' THEN
950 IF NEW.osm_type = 'R' THEN
951 NEW.rank_search := 16;
953 NEW.rank_search := 17;
955 NEW.rank_address := 0;
956 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
957 NEW.rank_search := 27;
958 NEW.rank_address := NEW.rank_search;
959 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
960 NEW.rank_search := 26;
961 NEW.rank_address := NEW.rank_search;
962 ELSEIF NEW.class = 'mountain_pass' THEN
963 NEW.rank_search := 20;
964 NEW.rank_address := 0;
969 IF NEW.rank_search > 30 THEN
970 NEW.rank_search := 30;
973 IF NEW.rank_address > 30 THEN
974 NEW.rank_address := 30;
977 IF (NEW.extratags -> 'capital') = 'yes' THEN
978 NEW.rank_search := NEW.rank_search - 1;
981 -- a country code make no sense below rank 4 (country)
982 IF NEW.rank_search < 4 THEN
983 NEW.calculated_country_code := NULL;
986 -- Block import below rank 22
987 -- IF NEW.rank_search > 22 THEN
991 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
993 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
995 IF NEW.rank_address > 0 THEN
996 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
997 -- Performance: We just can't handle re-indexing for country level changes
998 IF st_area(NEW.geometry) < 1 THEN
999 -- mark items within the geometry for re-indexing
1000 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1002 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1003 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1004 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));
1005 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1006 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));
1009 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1011 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1012 IF NEW.type='postcode' THEN
1014 ELSEIF NEW.rank_search < 16 THEN
1016 ELSEIF NEW.rank_search < 18 THEN
1018 ELSEIF NEW.rank_search < 20 THEN
1020 ELSEIF NEW.rank_search = 21 THEN
1022 ELSEIF NEW.rank_search < 24 THEN
1024 ELSEIF NEW.rank_search < 26 THEN
1025 diameter := 0.002; -- 100 to 200 meters
1026 ELSEIF NEW.rank_search < 28 THEN
1027 diameter := 0.001; -- 50 to 100 meters
1029 IF diameter > 0 THEN
1030 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1031 IF NEW.rank_search >= 26 THEN
1032 -- roads may cause reparenting for >27 rank places
1033 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1034 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1035 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1036 ELSEIF NEW.rank_search >= 16 THEN
1037 -- up to rank 16, street-less addresses may need reparenting
1038 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);
1040 -- for all other places the search terms may change as well
1041 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);
1048 -- add to tables for special search
1049 -- Note: won't work on initial import because the classtype tables
1050 -- do not yet exist. It won't hurt either.
1051 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1052 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1054 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1055 USING NEW.place_id, ST_Centroid(NEW.geometry);
1064 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1068 place_centroid GEOMETRY;
1071 IF OLD.indexed_status = 100 THEN
1072 delete from location_property_osmline where place_id = OLD.place_id;
1076 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1080 IF OLD.indexed_status = 2 and NEW.indexed_status=0 THEN
1081 -- do the reparenting: (finally here, because ALL places in placex, that are needed for reparenting, need to be up to date)
1082 -- (the osm interpolationline in location_property_osmline was marked for reparenting in placex_insert/placex_delete with index_status = 2
1083 -- => index.c: sets index_status back to 0
1084 -- => triggers this function)
1085 place_centroid := ST_PointOnSurface(NEW.linegeo);
1086 -- marking descendants for reparenting is not needed, because there are actually no descendants for interpolation lines
1087 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.street, null, NEW.partition, place_centroid, NEW.linegeo); -- addr_place (3rd param) is not necessarily needed
1094 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1099 place_centroid GEOMETRY;
1101 search_maxdistance FLOAT[];
1102 search_mindistance FLOAT[];
1103 address_havelevel BOOLEAN[];
1110 relation_members TEXT[];
1112 linkedplacex RECORD;
1113 search_diameter FLOAT;
1114 search_prevdiameter FLOAT;
1115 search_maxrank INTEGER;
1116 address_maxrank INTEGER;
1117 address_street_word_id INTEGER;
1118 address_street_word_ids INTEGER[];
1119 parent_place_id_rank BIGINT;
1124 location_rank_search INTEGER;
1125 location_distance FLOAT;
1126 location_parent GEOMETRY;
1127 location_isaddress BOOLEAN;
1128 location_keywords INTEGER[];
1130 default_language TEXT;
1131 name_vector INTEGER[];
1132 nameaddress_vector INTEGER[];
1134 linked_node_id BIGINT;
1139 IF OLD.indexed_status = 100 THEN
1140 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1141 delete from placex where place_id = OLD.place_id;
1145 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1149 -- ignore interpolated addresses
1150 IF NEW.class = 'place' and NEW.type = 'address' THEN
1154 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1156 --RAISE WARNING '%',NEW.place_id;
1157 --RAISE WARNING '%', NEW;
1159 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1160 -- Silently do nothing
1164 NEW.indexed_date = now();
1166 result := deleteSearchName(NEW.partition, NEW.place_id);
1167 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1168 result := deleteRoad(NEW.partition, NEW.place_id);
1169 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1170 UPDATE placex set linked_place_id = null, indexed_status = 2
1171 where linked_place_id = NEW.place_id;
1172 -- update not necessary for osmline, cause linked_place_id does not exist
1174 IF NEW.linked_place_id is not null THEN
1178 -- Speed up searches - just use the centroid of the feature
1179 -- cheaper but less acurate
1180 place_centroid := ST_PointOnSurface(NEW.geometry);
1181 NEW.centroid := null;
1183 -- recalculate country and partition
1184 IF NEW.rank_search = 4 THEN
1185 -- for countries, believe the mapped country code,
1186 -- so that we remain in the right partition if the boundaries
1188 NEW.partition := get_partition(lower(NEW.country_code));
1189 IF NEW.partition = 0 THEN
1190 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1191 NEW.partition := get_partition(NEW.calculated_country_code);
1193 NEW.calculated_country_code := lower(NEW.country_code);
1196 IF NEW.rank_search > 4 THEN
1197 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1198 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1200 NEW.calculated_country_code := NULL;
1202 NEW.partition := get_partition(NEW.calculated_country_code);
1205 -- waterway ways are linked when they are part of a relation and have the same class/type
1206 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1207 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1209 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1210 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1211 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1212 FOR linked_node_id IN SELECT place_id FROM placex
1213 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1214 and class = NEW.class and type = NEW.type
1215 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1217 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1224 -- Adding ourselves to the list simplifies address calculations later
1225 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1227 -- What level are we searching from
1228 search_maxrank := NEW.rank_search;
1230 -- Thought this wasn't needed but when we add new languages to the country_name table
1231 -- we need to update the existing names
1232 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1233 default_language := get_country_language_code(NEW.calculated_country_code);
1234 IF default_language IS NOT NULL THEN
1235 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1236 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1237 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1238 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1243 -- Initialise the name vector using our name
1244 name_vector := make_keywords(NEW.name);
1245 nameaddress_vector := '{}'::int[];
1248 address_havelevel[i] := false;
1251 NEW.importance := null;
1252 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1253 IF NEW.importance IS NULL THEN
1254 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;
1257 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1259 -- For low level elements we inherit from our parent road
1260 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1262 --RAISE WARNING 'finding street for %', NEW;
1264 -- We won't get a better centroid, besides these places are too small to care
1265 NEW.centroid := place_centroid;
1267 NEW.parent_place_id := null;
1269 -- if we have a POI and there is no address information,
1270 -- see if we can get it from a surrounding building
1271 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1272 AND NEW.housenumber IS NULL THEN
1273 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1274 and (housenumber is not null or street is not null or addr_place is not null)
1275 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1278 NEW.housenumber := location.housenumber;
1279 NEW.street := location.street;
1280 NEW.addr_place := location.addr_place;
1284 -- We have to find our parent road.
1285 -- Copy data from linked items (points on ways, addr:street links, relations)
1287 -- Is this object part of a relation?
1288 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1290 -- At the moment we only process one type of relation - associatedStreet
1291 IF relation.tags @> ARRAY['associatedStreet'] THEN
1292 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1293 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1294 --RAISE WARNING 'node in relation %',relation;
1295 SELECT place_id from placex where osm_type = 'W'
1296 and osm_id = substring(relation.members[i],2,200)::bigint
1297 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1304 -- Note that addr:street links can only be indexed once the street itself is indexed
1305 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1306 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1307 IF address_street_word_ids IS NOT NULL THEN
1308 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1309 NEW.parent_place_id := location.place_id;
1314 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1315 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1316 IF address_street_word_ids IS NOT NULL THEN
1317 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1318 NEW.parent_place_id := location.place_id;
1323 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1325 --RAISE WARNING 'x1';
1326 -- Is this node part of a way? search for the way in placex AND location_property_osmline (for interpolation lines)
1327 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.class, p.type, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w
1328 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)
1330 select q.place_id, q.osm_id, q.parent_place_id, 'place' as class, 'houses' as type, 30 as rank_search, null as street,
1331 null as addr_place from location_property_osmline q, planet_osm_ways x
1332 where q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1335 --RAISE WARNING '%', location;
1336 -- Way IS a road then we are on it - that must be our road
1337 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1338 --RAISE WARNING 'node in way that is a street %',location;
1339 NEW.parent_place_id := location.place_id;
1342 -- If this way is a street interpolation line then it is probably as good as we are going to get
1343 IF NEW.parent_place_id IS NULL AND location.class = 'place' and location.type='houses' THEN
1344 NEW.parent_place_id := location.parent_place_id;
1347 -- Is the WAY part of a relation
1348 IF NEW.parent_place_id IS NULL THEN
1349 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1351 -- At the moment we only process one type of relation - associatedStreet
1352 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1353 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1354 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1355 --RAISE WARNING 'node in way that is in a relation %',relation;
1356 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1357 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1364 -- If the way mentions a street or place address, try that for parenting.
1365 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1366 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1367 IF address_street_word_ids IS NOT NULL THEN
1368 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1369 NEW.parent_place_id := linkedplacex.place_id;
1374 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1375 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1376 IF address_street_word_ids IS NOT NULL THEN
1377 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1378 NEW.parent_place_id := linkedplacex.place_id;
1387 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1388 -- Still nothing, just use the nearest road
1389 IF NEW.parent_place_id IS NULL THEN
1390 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1391 NEW.parent_place_id := location.place_id;
1396 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1398 -- If we didn't find any road fallback to standard method
1399 IF NEW.parent_place_id IS NOT NULL THEN
1401 -- Get the details of the parent road
1402 select * from search_name where place_id = NEW.parent_place_id INTO location;
1403 NEW.calculated_country_code := location.country_code;
1405 -- Merge the postcode into the parent's address if necessary XXXX
1406 IF NEW.postcode IS NOT NULL THEN
1407 isin_tokens := '{}'::int[];
1408 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1409 IF address_street_word_id is not null
1410 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1411 isin_tokens := isin_tokens || address_street_word_id;
1413 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1414 IF address_street_word_id is not null
1415 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1416 isin_tokens := isin_tokens || address_street_word_id;
1418 IF isin_tokens != '{}'::int[] THEN
1420 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1421 WHERE place_id = NEW.parent_place_id;
1425 --RAISE WARNING '%', NEW.name;
1426 -- If there is no name it isn't searchable, don't bother to create a search record
1427 IF NEW.name is NULL THEN
1431 -- Merge address from parent
1432 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1433 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1435 -- Performance, it would be more acurate to do all the rest of the import
1436 -- process but it takes too long
1437 -- Just be happy with inheriting from parent road only
1439 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1440 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1443 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1450 -- RAISE WARNING ' INDEXING Started:';
1451 -- RAISE WARNING ' INDEXING: %',NEW;
1453 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1455 -- see if we have any special relation members
1456 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1458 -- RAISE WARNING 'get_osm_rel_members, label';
1459 IF relation_members IS NOT NULL THEN
1460 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1462 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1463 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1465 -- If we don't already have one use this as the centre point of the geometry
1466 IF NEW.centroid IS NULL THEN
1467 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1470 -- merge in the label name, re-init word vector
1471 IF NOT linkedPlacex.name IS NULL THEN
1472 NEW.name := linkedPlacex.name || NEW.name;
1473 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1476 -- merge in extra tags
1477 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1479 -- mark the linked place (excludes from search results)
1480 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1482 -- keep a note of the node id in case we need it for wikipedia in a bit
1483 linked_node_id := linkedPlacex.osm_id;
1488 IF NEW.centroid IS NULL THEN
1490 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1492 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1493 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1495 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1496 -- But that can be fixed by explicitly setting the label in the data
1497 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1498 AND NEW.rank_address = linkedPlacex.rank_address THEN
1500 -- If we don't already have one use this as the centre point of the geometry
1501 IF NEW.centroid IS NULL THEN
1502 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1505 -- merge in the name, re-init word vector
1506 IF NOT linkedPlacex.name IS NULL THEN
1507 NEW.name := linkedPlacex.name || NEW.name;
1508 name_vector := make_keywords(NEW.name);
1511 -- merge in extra tags
1512 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1514 -- mark the linked place (excludes from search results)
1515 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1517 -- keep a note of the node id in case we need it for wikipedia in a bit
1518 linked_node_id := linkedPlacex.osm_id;
1530 -- Name searches can be done for ways as well as relations
1531 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1533 -- not found one yet? how about doing a name search
1534 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1536 FOR linkedPlacex IN select placex.* from placex WHERE
1537 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1538 AND placex.rank_address = NEW.rank_address
1539 AND placex.place_id != NEW.place_id
1540 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1541 AND st_covers(NEW.geometry, placex.geometry)
1544 -- If we don't already have one use this as the centre point of the geometry
1545 IF NEW.centroid IS NULL THEN
1546 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1549 -- merge in the name, re-init word vector
1550 NEW.name := linkedPlacex.name || NEW.name;
1551 name_vector := make_keywords(NEW.name);
1553 -- merge in extra tags
1554 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1556 -- mark the linked place (excludes from search results)
1557 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1559 -- keep a note of the node id in case we need it for wikipedia in a bit
1560 linked_node_id := linkedPlacex.osm_id;
1564 IF NEW.centroid IS NOT NULL THEN
1565 place_centroid := NEW.centroid;
1566 -- Place might have had only a name tag before but has now received translations
1567 -- from the linked place. Make sure a name tag for the default language exists in
1569 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1570 default_language := get_country_language_code(NEW.calculated_country_code);
1571 IF default_language IS NOT NULL THEN
1572 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1573 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1574 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1575 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1581 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1582 IF NEW.importance is null THEN
1583 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1585 -- Still null? how about looking it up by the node id
1586 IF NEW.importance IS NULL THEN
1587 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;
1592 -- make sure all names are in the word table
1593 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1594 perform create_country(NEW.name, lower(NEW.country_code));
1597 NEW.parent_place_id = 0;
1598 parent_place_id_rank = 0;
1601 -- convert isin to array of tokenids
1602 isin_tokens := '{}'::int[];
1603 IF NEW.isin IS NOT NULL THEN
1604 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1605 IF array_upper(isin, 1) IS NOT NULL THEN
1606 FOR i IN 1..array_upper(isin, 1) LOOP
1607 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1608 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1609 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1610 isin_tokens := isin_tokens || address_street_word_id;
1613 -- merge word into address vector
1614 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1615 IF address_street_word_id IS NOT NULL THEN
1616 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1621 IF NEW.postcode IS NOT NULL THEN
1622 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1623 IF array_upper(isin, 1) IS NOT NULL THEN
1624 FOR i IN 1..array_upper(isin, 1) LOOP
1625 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1626 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1627 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1628 isin_tokens := isin_tokens || address_street_word_id;
1631 -- merge into address vector
1632 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1633 IF address_street_word_id IS NOT NULL THEN
1634 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1640 -- %NOTIGERDATA% IF 0 THEN
1641 -- for the USA we have an additional address table. Merge in zip codes from there too
1642 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1643 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1644 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1645 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1646 isin_tokens := isin_tokens || address_street_word_id;
1648 -- also merge in the single word version
1649 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1650 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1653 -- %NOTIGERDATA% END IF;
1655 -- RAISE WARNING 'ISIN: %', isin_tokens;
1657 -- Process area matches
1658 location_rank_search := 0;
1659 location_distance := 0;
1660 location_parent := NULL;
1661 -- added ourself as address already
1662 address_havelevel[NEW.rank_address] := true;
1663 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1664 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1666 --RAISE WARNING ' AREA: %',location;
1668 IF location.rank_address != location_rank_search THEN
1669 location_rank_search := location.rank_address;
1670 IF location.isguess THEN
1671 location_distance := location.distance * 1.5;
1673 IF location.rank_address <= 12 THEN
1674 -- for county and above, if we have an area consider that exact
1675 -- (It would be nice to relax the constraint for places close to
1676 -- the boundary but we'd need the exact geometry for that. Too
1678 location_distance = 0;
1680 -- Below county level remain slightly fuzzy.
1681 location_distance := location.distance * 0.5;
1685 CONTINUE WHEN location.keywords <@ location_keywords;
1688 IF location.distance < location_distance OR NOT location.isguess THEN
1689 location_keywords := location.keywords;
1691 location_isaddress := NOT address_havelevel[location.rank_address];
1692 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1693 location_isaddress := ST_Contains(location_parent,location.centroid);
1696 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1697 -- Add it to the list of search terms
1698 IF location.rank_search > 4 THEN
1699 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1701 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1703 IF location_isaddress THEN
1705 address_havelevel[location.rank_address] := true;
1706 IF NOT location.isguess THEN
1707 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1710 IF location.rank_address > parent_place_id_rank THEN
1711 NEW.parent_place_id = location.place_id;
1712 parent_place_id_rank = location.rank_address;
1717 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1723 -- try using the isin value to find parent places
1724 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1725 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1726 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1727 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1729 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1731 --RAISE WARNING ' ISIN: %',location;
1733 IF location.rank_search > 4 THEN
1734 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1735 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1736 address_havelevel[location.rank_address] := true;
1738 IF location.rank_address > parent_place_id_rank THEN
1739 NEW.parent_place_id = location.place_id;
1740 parent_place_id_rank = location.rank_address;
1750 -- for long ways we should add search terms for the entire length
1751 IF st_length(NEW.geometry) > 0.05 THEN
1753 location_rank_search := 0;
1754 location_distance := 0;
1756 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1758 IF location.rank_address != location_rank_search THEN
1759 location_rank_search := location.rank_address;
1760 location_distance := location.distance * 1.5;
1763 IF location.rank_search > 4 AND location.distance < location_distance THEN
1765 -- Add it to the list of search terms
1766 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1767 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1775 -- if we have a name add this to the name search table
1776 IF NEW.name IS NOT NULL THEN
1778 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1779 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1782 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1783 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1786 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1790 -- If we've not managed to pick up a better one - default centroid
1791 IF NEW.centroid IS NULL THEN
1792 NEW.centroid := place_centroid;
1800 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1806 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1808 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1809 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1810 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1811 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1813 IF OLD.rank_address < 30 THEN
1815 -- mark everything linked to this place for re-indexing
1816 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1817 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1818 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1820 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1821 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1823 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1824 b := deleteRoad(OLD.partition, OLD.place_id);
1826 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1827 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1828 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1829 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1830 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1834 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1836 IF OLD.rank_address < 26 THEN
1837 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1840 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1842 IF OLD.name is not null THEN
1843 b := deleteSearchName(OLD.partition, OLD.place_id);
1846 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1848 DELETE FROM place_addressline where place_id = OLD.place_id;
1850 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1852 -- remove from tables for special search
1853 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1854 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1856 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1859 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1867 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1873 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1875 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1876 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1877 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;
1879 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1885 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;
1887 -- interpolations are special
1888 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1889 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1898 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1903 existingplacex RECORD;
1904 existingline RECORD;
1905 existinggeometry GEOMETRY;
1906 existingplace_id BIGINT;
1911 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1912 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1913 -- filter wrong tupels
1914 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
1915 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1916 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1917 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1921 -- decide, whether its an osm interpolation line => insert_osmline, or else just insert into placex
1922 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1923 -- Have we already done this place?
1924 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;
1926 -- Get the existing place_id
1927 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1929 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1930 -- My generated 'place' types are causing havok because they overlap with real keys
1931 -- TODO: move them to their own special purpose key/class to avoid collisions
1932 IF existing.osm_type IS NULL THEN
1933 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1936 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1937 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1939 -- To paraphrase, if there isn't an existing item
1940 IF existingline.osm_id IS NULL THEN
1941 -- insert new line into location_property_osmline, use function insert_osmline
1942 i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry);
1945 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1946 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
1947 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1948 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1949 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
1950 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1951 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1952 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1953 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
1954 OR existing.geometry::text != NEW.geometry::text
1959 housenumber = NEW.housenumber,
1960 street = NEW.street,
1961 addr_place = NEW.addr_place,
1963 postcode = NEW.postcode,
1964 country_code = NEW.country_code,
1965 extratags = NEW.extratags,
1966 admin_level = NEW.admin_level,
1967 geometry = NEW.geometry
1968 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1970 -- 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)
1971 delete from location_property_osmline where osm_id = NEW.osm_id;
1972 i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry);
1975 -- for interpolations invalidate all nodes on the line
1976 update placex p set indexed_status = 2 from planet_osm_ways w where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
1979 ELSE -- insert to placex
1981 IF FALSE and NEW.osm_type = 'R' THEN
1982 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;
1983 --DEBUG: RAISE WARNING '%', existingplacex;
1985 -- Patch in additional country names
1986 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1987 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1990 -- Have we already done this place?
1991 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;
1993 -- Get the existing place_id
1994 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;
1996 -- Handle a place changing type by removing the old data
1997 -- My generated 'place' types are causing havok because they overlap with real keys
1998 -- TODO: move them to their own special purpose key/class to avoid collisions
1999 IF existing.osm_type IS NULL THEN
2000 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2003 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2004 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2007 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2008 AND st_area(existing.geometry) > 0.02
2009 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2010 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2012 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2013 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2017 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2018 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2020 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2021 IF existingplacex.osm_type IS NULL OR
2022 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2025 IF existingplacex.osm_type IS NOT NULL THEN
2026 -- sanity check: ignore admin_level changes on places with too many active children
2027 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2028 --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;
2029 --LIMIT INDEXING: IF i > 100000 THEN
2030 --LIMIT INDEXING: RETURN null;
2031 --LIMIT INDEXING: END IF;
2034 IF existing.osm_type IS NOT NULL THEN
2035 -- pathological case caused by the triggerless copy into place during initial import
2036 -- force delete even for large areas, it will be reinserted later
2037 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;
2038 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2041 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2042 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2043 street, addr_place, isin, postcode, country_code, extratags, geometry)
2044 values (NEW.osm_type
2060 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2065 -- Various ways to do the update
2067 -- Debug, what's changed?
2069 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2070 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2072 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2073 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2075 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2076 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2078 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2079 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2081 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2082 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2084 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2085 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2087 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2088 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2092 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2093 IF existing.geometry::text != NEW.geometry::text
2094 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2095 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2098 -- Get the version of the geometry actually used (in placex table)
2099 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;
2101 -- Performance limit
2102 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2104 -- 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
2105 update placex set indexed_status = 2 where indexed_status = 0 and
2106 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2107 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2108 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2110 update placex set indexed_status = 2 where indexed_status = 0 and
2111 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2112 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2113 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2120 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2121 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2122 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2123 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2124 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2125 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2126 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2127 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2128 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2129 OR existing.geometry::text != NEW.geometry::text
2134 housenumber = NEW.housenumber,
2135 street = NEW.street,
2136 addr_place = NEW.addr_place,
2138 postcode = NEW.postcode,
2139 country_code = NEW.country_code,
2140 extratags = NEW.extratags,
2141 admin_level = NEW.admin_level,
2142 geometry = NEW.geometry
2143 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2146 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2147 IF NEW.postcode IS NULL THEN
2148 -- postcode was deleted, no longer retain in placex
2149 DELETE FROM placex where place_id = existingplacex.place_id;
2153 NEW.name := hstore('ref', NEW.postcode);
2158 housenumber = NEW.housenumber,
2159 street = NEW.street,
2160 addr_place = NEW.addr_place,
2162 postcode = NEW.postcode,
2163 country_code = NEW.country_code,
2164 parent_place_id = null,
2165 extratags = NEW.extratags,
2166 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2168 geometry = NEW.geometry
2169 where place_id = existingplacex.place_id;
2171 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2172 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2173 -- needed for test case features/db/import: Scenario: addr:street added to housenumbers
2174 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2175 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2176 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);
2181 -- Abort the add (we modified the existing place instead)
2186 $$ LANGUAGE plpgsql;
2189 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2194 IF name is null THEN
2198 FOR j IN 1..array_upper(languagepref,1) LOOP
2199 IF name ? languagepref[j] THEN
2200 result := trim(name->languagepref[j]);
2201 IF result != '' THEN
2207 -- anything will do as a fallback - just take the first name type thing there is
2208 RETURN trim((avals(name))[1]);
2211 LANGUAGE plpgsql IMMUTABLE;
2214 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2225 search := ARRAY['ref'];
2228 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2231 select rank_address,name,distance,length(name::text) as namelength
2232 from place_addressline join placex on (address_place_id = placex.place_id)
2233 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2234 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2236 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2237 FOR j IN 1..array_upper(search, 1) LOOP
2238 FOR k IN 1..array_upper(location.name, 1) LOOP
2239 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
2240 result[(100 - location.rank_address)] := trim(location.name[k].value);
2241 found := location.rank_address;
2248 RETURN array_to_string(result,', ');
2253 --housenumber only needed for tiger data
2254 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2266 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2267 currresult := trim(get_name_by_language(location.name, languagepref));
2268 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2269 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2270 prevresult := currresult;
2274 RETURN array_to_string(result,', ');
2279 DROP TYPE IF EXISTS addressline CASCADE;
2280 create type addressline as (
2287 admin_level INTEGER,
2290 rank_address INTEGER,
2294 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2297 for_place_id BIGINT;
2302 countrylocation RECORD;
2303 searchcountrycode varchar(2);
2304 searchhousenumber TEXT;
2305 searchhousename HSTORE;
2306 searchrankaddress INTEGER;
2307 searchpostcode TEXT;
2313 -- first query osmline (interpolation lines)
2314 select parent_place_id, calculated_country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2315 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2316 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2317 IF for_place_id IS NOT NULL THEN
2318 searchhousenumber = in_housenumber::text;
2321 --then query tiger data
2322 -- %NOTIGERDATA% IF 0 THEN
2323 IF for_place_id IS NULL THEN
2324 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2325 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2326 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2327 IF for_place_id IS NOT NULL THEN
2328 searchhousenumber = in_housenumber::text;
2331 -- %NOTIGERDATA% END IF;
2333 -- %NOAUXDATA% IF 0 THEN
2334 IF for_place_id IS NULL THEN
2335 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2336 WHERE place_id = in_place_id
2337 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2339 -- %NOAUXDATA% END IF;
2341 IF for_place_id IS NULL THEN
2342 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2343 WHERE place_id = in_place_id and rank_address = 30
2344 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2347 IF for_place_id IS NULL THEN
2348 select coalesce(linked_place_id, place_id), calculated_country_code,
2349 housenumber, rank_search, postcode, null
2350 from placex where place_id = in_place_id
2351 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2354 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2357 hadcountry := false;
2359 select placex.place_id, osm_type, osm_id,
2360 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2361 class, type, admin_level, true as fromarea, true as isaddress,
2362 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2363 0 as distance, calculated_country_code, postcode
2365 where place_id = for_place_id
2367 --RAISE WARNING '%',location;
2368 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2369 searchcountrycode := location.calculated_country_code;
2371 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2372 location.isaddress := FALSE;
2374 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2375 searchpostcode := location.postcode;
2377 IF location.rank_address = 4 AND location.isaddress THEN
2380 IF location.rank_address < 4 AND NOT hadcountry THEN
2381 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2382 IF countryname IS NOT NULL THEN
2383 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2384 RETURN NEXT countrylocation;
2387 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2388 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2389 location.distance)::addressline;
2390 RETURN NEXT countrylocation;
2391 found := location.rank_address;
2395 select placex.place_id, osm_type, osm_id,
2396 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2397 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2398 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2399 admin_level, fromarea, isaddress,
2400 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,
2401 distance,calculated_country_code,postcode
2402 from place_addressline join placex on (address_place_id = placex.place_id)
2403 where place_addressline.place_id = for_place_id
2404 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2405 and address_place_id != for_place_id
2406 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2407 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2409 --RAISE WARNING '%',location;
2410 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2411 searchcountrycode := location.calculated_country_code;
2413 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2414 location.isaddress := FALSE;
2416 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2417 searchpostcode := location.postcode;
2419 IF location.rank_address = 4 AND location.isaddress THEN
2422 IF location.rank_address < 4 AND NOT hadcountry THEN
2423 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2424 IF countryname IS NOT NULL THEN
2425 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2426 RETURN NEXT countrylocation;
2429 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2430 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2431 location.distance)::addressline;
2432 RETURN NEXT countrylocation;
2433 found := location.rank_address;
2437 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2438 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2439 IF countryname IS NOT NULL THEN
2440 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2441 RETURN NEXT location;
2445 IF searchcountrycode IS NOT NULL THEN
2446 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2447 RETURN NEXT location;
2450 IF searchhousename IS NOT NULL THEN
2451 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2452 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2453 RETURN NEXT location;
2456 IF searchhousenumber IS NOT NULL THEN
2457 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2458 RETURN NEXT location;
2461 IF searchpostcode IS NOT NULL THEN
2462 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2463 RETURN NEXT location;
2472 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2475 numfeatures integer;
2479 housenumber = place.housenumber,
2480 street = place.street,
2481 addr_place = place.addr_place,
2483 postcode = place.postcode,
2484 country_code = place.country_code,
2485 parent_place_id = null
2487 where placex.place_id = search_place_id
2488 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2489 and place.class = placex.class and place.type = placex.type;
2490 update placex set indexed_status = 2 where place_id = search_place_id;
2491 update placex set indexed_status = 0 where place_id = search_place_id;
2497 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2503 ELSEIF rank < 4 THEN
2505 ELSEIF rank < 8 THEN
2507 ELSEIF rank < 12 THEN
2509 ELSEIF rank < 16 THEN
2511 ELSEIF rank = 16 THEN
2513 ELSEIF rank = 17 THEN
2514 RETURN 'Town / Island';
2515 ELSEIF rank = 18 THEN
2516 RETURN 'Village / Hamlet';
2517 ELSEIF rank = 20 THEN
2519 ELSEIF rank = 21 THEN
2520 RETURN 'Postcode Area';
2521 ELSEIF rank = 22 THEN
2522 RETURN 'Croft / Farm / Locality / Islet';
2523 ELSEIF rank = 23 THEN
2524 RETURN 'Postcode Area';
2525 ELSEIF rank = 25 THEN
2526 RETURN 'Postcode Point';
2527 ELSEIF rank = 26 THEN
2528 RETURN 'Street / Major Landmark';
2529 ELSEIF rank = 27 THEN
2530 RETURN 'Minory Street / Path';
2531 ELSEIF rank = 28 THEN
2532 RETURN 'House / Building';
2534 RETURN 'Other: '||rank;
2541 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2547 ELSEIF rank < 2 THEN
2549 ELSEIF rank < 4 THEN
2551 ELSEIF rank = 5 THEN
2553 ELSEIF rank < 8 THEN
2555 ELSEIF rank < 12 THEN
2557 ELSEIF rank < 16 THEN
2559 ELSEIF rank = 16 THEN
2561 ELSEIF rank = 17 THEN
2562 RETURN 'Town / Village / Hamlet';
2563 ELSEIF rank = 20 THEN
2565 ELSEIF rank = 21 THEN
2566 RETURN 'Postcode Area';
2567 ELSEIF rank = 22 THEN
2568 RETURN 'Croft / Farm / Locality / Islet';
2569 ELSEIF rank = 23 THEN
2570 RETURN 'Postcode Area';
2571 ELSEIF rank = 25 THEN
2572 RETURN 'Postcode Point';
2573 ELSEIF rank = 26 THEN
2574 RETURN 'Street / Major Landmark';
2575 ELSEIF rank = 27 THEN
2576 RETURN 'Minory Street / Path';
2577 ELSEIF rank = 28 THEN
2578 RETURN 'House / Building';
2580 RETURN 'Other: '||rank;
2587 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2588 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2593 place_centroid GEOMETRY;
2594 out_partition INTEGER;
2595 out_parent_place_id BIGINT;
2597 address_street_word_id INTEGER;
2602 place_centroid := ST_Centroid(pointgeo);
2603 out_partition := get_partition(in_countrycode);
2604 out_parent_place_id := null;
2606 address_street_word_id := get_name_id(make_standard_name(in_street));
2607 IF address_street_word_id IS NOT NULL THEN
2608 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2609 out_parent_place_id := location.place_id;
2613 IF out_parent_place_id IS NULL THEN
2614 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2615 out_parent_place_id := location.place_id;
2619 out_postcode := in_postcode;
2620 IF out_postcode IS NULL THEN
2621 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2623 IF out_postcode IS NULL THEN
2624 out_postcode := getNearestPostcode(out_partition, place_centroid);
2628 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2629 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2630 newpoints := newpoints + 1;
2637 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2644 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2645 IF members[i+1] = member THEN
2646 result := result || members[i];
2655 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2661 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2662 IF members[i+1] = ANY(memberLabels) THEN
2663 RETURN NEXT members[i];
2672 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2673 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2675 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2676 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
2677 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2678 ), '') AS bytea), 'UTF8');
2680 LANGUAGE SQL IMMUTABLE STRICT;
2682 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2686 RETURN decode_url_part(p);
2688 WHEN others THEN return null;
2691 LANGUAGE plpgsql IMMUTABLE;
2693 DROP TYPE wikipedia_article_match CASCADE;
2694 create type wikipedia_article_match as (
2700 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2706 wiki_article_title TEXT;
2707 wiki_article_language TEXT;
2708 result wikipedia_article_match;
2710 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'];
2712 WHILE langs[i] IS NOT NULL LOOP
2713 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2714 IF wiki_article is not null THEN
2715 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2716 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2717 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2718 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2719 wiki_article := replace(wiki_article,' ','_');
2720 IF strpos(wiki_article, ':') IN (3,4) THEN
2721 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2722 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2724 wiki_article_title := trim(wiki_article);
2725 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;
2728 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2729 from wikipedia_article
2730 where language = wiki_article_language and
2731 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2733 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2734 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2735 where wikipedia_redirect.language = wiki_article_language and
2736 (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'\\',''))
2737 order by importance desc limit 1 INTO result;
2739 IF result.language is not null THEN
2750 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2751 RETURNS SETOF GEOMETRY
2765 remainingdepth INTEGER;
2770 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2772 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2773 RETURN NEXT geometry;
2777 remainingdepth := maxdepth - 1;
2778 area := ST_AREA(geometry);
2779 IF remainingdepth < 1 OR area < maxarea THEN
2780 RETURN NEXT geometry;
2784 xmin := st_xmin(geometry);
2785 xmax := st_xmax(geometry);
2786 ymin := st_ymin(geometry);
2787 ymax := st_ymax(geometry);
2788 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2790 -- if the geometry completely covers the box don't bother to slice any more
2791 IF ST_AREA(secbox) = area THEN
2792 RETURN NEXT geometry;
2796 xmid := (xmin+xmax)/2;
2797 ymid := (ymin+ymax)/2;
2800 FOR seg IN 1..4 LOOP
2803 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2806 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2809 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2812 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2815 IF st_intersects(geometry, secbox) THEN
2816 secgeo := st_intersection(geometry, secbox);
2817 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2818 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2819 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2821 RETURN NEXT geo.geom;
2833 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2834 RETURNS SETOF GEOMETRY
2839 -- 10000000000 is ~~ 1x1 degree
2840 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2841 RETURN NEXT geo.geom;
2849 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2853 osmtype character(1);
2857 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2858 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2859 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2860 -- force delete from place/placex by making it a very small geometry
2861 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;
2862 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2869 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2877 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2878 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2879 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2880 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2881 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2882 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2883 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));
2884 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2885 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));
2891 ELSEIF rank < 18 THEN
2893 ELSEIF rank < 20 THEN
2895 ELSEIF rank = 21 THEN
2897 ELSEIF rank < 24 THEN
2899 ELSEIF rank < 26 THEN
2900 diameter := 0.002; -- 100 to 200 meters
2901 ELSEIF rank < 28 THEN
2902 diameter := 0.001; -- 50 to 100 meters
2904 IF diameter > 0 THEN
2906 -- roads may cause reparenting for >27 rank places
2907 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2908 ELSEIF rank >= 16 THEN
2909 -- up to rank 16, street-less addresses may need reparenting
2910 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);
2912 -- for all other places the search terms may change as well
2913 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);