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);
583 -- find the parant road of an interpolation
584 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
585 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
590 parent_place_id BIGINT;
591 address_street_word_ids INTEGER[];
597 addr_street = street;
600 IF addr_street is null and addr_place is null THEN
601 select nodes from planet_osm_ways where id = wayid INTO waynodes;
602 FOR location IN SELECT placex.street, placex.addr_place from placex
603 where osm_type = 'N' and osm_id = ANY(waynodes)
604 and (placex.street is not null or placex.addr_place is not null)
605 and indexed_status < 100
607 addr_street = location.street;
608 addr_place = location.addr_place;
612 IF addr_street IS NOT NULL THEN
613 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
614 IF address_street_word_ids IS NOT NULL THEN
615 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
616 parent_place_id := location.place_id;
621 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
622 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
623 IF address_street_word_ids IS NOT NULL THEN
624 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
625 parent_place_id := location.place_id;
630 IF parent_place_id is null THEN
631 FOR location IN SELECT place_id FROM placex
632 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
633 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
635 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
637 parent_place_id := location.place_id;
641 IF parent_place_id is null THEN
645 RETURN parent_place_id;
650 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT,
651 parent_id BIGINT, partition INTEGER,
652 country_code TEXT, geometry_sector INTEGER,
653 defpostalcode TEXT, geom GEOMETRY) RETURNS INTEGER
665 orginalstartnumber INTEGER;
666 originalnumberrange INTEGER;
674 delete from placex where osm_type = 'W' and osm_id = wayid
675 and class = 'place' and type = 'address';
677 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
679 ELSEIF interpolationtype = 'all' THEN
681 ELSEIF interpolationtype ~ '^\d+$' THEN
682 stepsize := interpolationtype::INTEGER;
687 select nodes from planet_osm_ways where id = wayid INTO waynodes;
689 IF array_upper(waynodes, 1) IS NULL THEN
697 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
699 -- If there is a place of a type other than place/house, use that because
700 -- it is guaranteed to be the original node. For place/house types use the
701 -- one with the smallest id because the original node was created first.
702 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
703 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
704 and indexed_status < 100 and housenumber is not NULL
705 order by (type = 'address'),place_id limit 1 INTO nextnode;
706 IF nextnode.place_id IS NOT NULL THEN
708 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
709 -- Make sure that the point is actually on the line. That might
710 -- be a bit paranoid but ensures that the algorithm still works
711 -- should osm2pgsql attempt to repair geometries.
712 splitline := split_line_on_node(linegeo, nextnode.geometry);
713 sectiongeo := ST_GeometryN(splitline, 1);
714 linegeo := ST_GeometryN(splitline, 2);
716 sectiongeo = linegeo;
718 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
720 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
721 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
722 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
724 IF (startnumber > endnumber) THEN
725 housenum := endnumber;
726 endnumber := startnumber;
727 startnumber := housenum;
728 sectiongeo := ST_Reverse(sectiongeo);
730 orginalstartnumber := startnumber;
731 originalnumberrange := endnumber - startnumber;
733 startnumber := startnumber + stepsize;
734 -- correct for odd/even
735 IF (interpolationtype = 'odd' AND startnumber%2 = 0)
736 OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
737 startnumber := startnumber - 1;
739 endnumber := endnumber - 1;
741 -- keep for compatibility with previous versions
742 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id
743 and place_id != prevnode.place_id and class = 'place'
745 FOR housenum IN startnumber..endnumber BY stepsize LOOP
746 pointgeo := ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float);
747 insert into placex (place_id, partition, osm_type, osm_id,
748 class, type, admin_level, housenumber,
750 country_code, parent_place_id, rank_address, rank_search,
751 indexed_status, indexed_date, geometry_sector,
752 calculated_country_code, centroid, geometry)
753 values (nextval('seq_place'), partition, 'W', wayid,
754 'place', 'address', prevnode.admin_level, housenum,
755 coalesce(prevnode.postcode, defpostalcode),
756 prevnode.country_code, parent_id, 30, 30,
757 0, now(), geometry_sector, country_code,
759 newpoints := newpoints + 1;
760 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
764 -- early break if we are out of line string,
765 -- might happen when a line string loops back on itself
766 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
770 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
771 prevnode := nextnode;
775 --RAISE WARNING 'interpolation points % ',newpoints;
782 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
788 country_code VARCHAR(2);
789 default_language VARCHAR(10);
793 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
795 -- ignore interpolated addresses
796 IF NEW.class = 'place' and NEW.type = 'address' THEN
800 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
801 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
802 RAISE WARNING 'invalid geometry %',NEW.osm_id;
806 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
808 NEW.place_id := nextval('seq_place');
809 NEW.indexed_status := 1; --STATUS_NEW
811 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
813 NEW.partition := get_partition(NEW.calculated_country_code);
814 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
816 -- copy 'name' to or from the default language (if there is a default language)
817 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
818 default_language := get_country_language_code(NEW.calculated_country_code);
819 IF default_language IS NOT NULL THEN
820 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
821 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
822 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
823 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
828 IF NEW.admin_level > 15 THEN
829 NEW.admin_level := 15;
832 IF NEW.housenumber IS NOT NULL THEN
833 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
836 IF NEW.osm_type = 'X' THEN
837 -- E'X'ternal records should already be in the right format so do nothing
839 NEW.rank_search := 30;
840 NEW.rank_address := NEW.rank_search;
842 -- By doing in postgres we have the country available to us - currently only used for postcode
843 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
845 IF NEW.postcode IS NULL THEN
846 -- most likely just a part of a multipolygon postcode boundary, throw it away
850 NEW.name := hstore('ref', NEW.postcode);
852 IF NEW.calculated_country_code = 'gb' THEN
854 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
855 NEW.rank_search := 25;
856 NEW.rank_address := 5;
857 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
858 NEW.rank_search := 23;
859 NEW.rank_address := 5;
860 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
861 NEW.rank_search := 21;
862 NEW.rank_address := 5;
865 ELSEIF NEW.calculated_country_code = 'sg' THEN
867 IF NEW.postcode ~ '^([0-9]{6})$' THEN
868 NEW.rank_search := 25;
869 NEW.rank_address := 11;
872 ELSEIF NEW.calculated_country_code = 'de' THEN
874 IF NEW.postcode ~ '^([0-9]{5})$' THEN
875 NEW.rank_search := 21;
876 NEW.rank_address := 11;
880 -- Guess at the postcode format and coverage (!)
881 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
882 NEW.rank_search := 21;
883 NEW.rank_address := 11;
885 -- Does it look splitable into and area and local code?
886 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
888 IF postcode IS NOT NULL THEN
889 NEW.rank_search := 25;
890 NEW.rank_address := 11;
891 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
892 NEW.rank_search := 21;
893 NEW.rank_address := 11;
898 ELSEIF NEW.class = 'place' THEN
899 IF NEW.type in ('continent') THEN
900 NEW.rank_search := 2;
901 NEW.rank_address := NEW.rank_search;
902 NEW.calculated_country_code := NULL;
903 ELSEIF NEW.type in ('sea') THEN
904 NEW.rank_search := 2;
905 NEW.rank_address := 0;
906 NEW.calculated_country_code := NULL;
907 ELSEIF NEW.type in ('country') THEN
908 NEW.rank_search := 4;
909 NEW.rank_address := NEW.rank_search;
910 ELSEIF NEW.type in ('state') THEN
911 NEW.rank_search := 8;
912 NEW.rank_address := NEW.rank_search;
913 ELSEIF NEW.type in ('region') THEN
914 NEW.rank_search := 18; -- dropped from previous value of 10
915 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
916 ELSEIF NEW.type in ('county') THEN
917 NEW.rank_search := 12;
918 NEW.rank_address := NEW.rank_search;
919 ELSEIF NEW.type in ('city') THEN
920 NEW.rank_search := 16;
921 NEW.rank_address := NEW.rank_search;
922 ELSEIF NEW.type in ('island') THEN
923 NEW.rank_search := 17;
924 NEW.rank_address := 0;
925 ELSEIF NEW.type in ('town') THEN
926 NEW.rank_search := 18;
927 NEW.rank_address := 16;
928 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
929 NEW.rank_search := 19;
930 NEW.rank_address := 16;
931 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
932 NEW.rank_search := 20;
933 NEW.rank_address := NEW.rank_search;
934 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
935 NEW.rank_search := 20;
936 NEW.rank_address := 0;
937 -- Irish townlands, tagged as place=locality and locality=townland
938 IF (NEW.extratags -> 'locality') = 'townland' THEN
939 NEW.rank_address := 20;
941 ELSEIF NEW.type in ('neighbourhood') THEN
942 NEW.rank_search := 22;
943 NEW.rank_address := 22;
944 ELSEIF NEW.type in ('house','building') THEN
945 NEW.rank_search := 30;
946 NEW.rank_address := NEW.rank_search;
947 ELSEIF NEW.type in ('houses') THEN
948 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
949 NEW.rank_search := 28;
950 NEW.rank_address := 0;
953 ELSEIF NEW.class = 'boundary' THEN
954 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
955 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
958 NEW.rank_search := NEW.admin_level * 2;
959 IF NEW.type = 'administrative' THEN
960 NEW.rank_address := NEW.rank_search;
962 NEW.rank_address := 0;
964 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
965 NEW.rank_search := 22;
966 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
967 NEW.rank_address := NEW.rank_search;
969 NEW.rank_address := 0;
971 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
972 NEW.rank_search := 18;
973 NEW.rank_address := 0;
974 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
975 NEW.rank_search := 4;
976 NEW.rank_address := NEW.rank_search;
977 -- any feature more than 5 square miles is probably worth indexing
978 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
979 NEW.rank_search := 22;
980 NEW.rank_address := 0;
981 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
983 ELSEIF NEW.class = 'waterway' THEN
984 IF NEW.osm_type = 'R' THEN
985 NEW.rank_search := 16;
987 NEW.rank_search := 17;
989 NEW.rank_address := 0;
990 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
991 NEW.rank_search := 27;
992 NEW.rank_address := NEW.rank_search;
993 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
994 NEW.rank_search := 26;
995 NEW.rank_address := NEW.rank_search;
996 ELSEIF NEW.class = 'mountain_pass' THEN
997 NEW.rank_search := 20;
998 NEW.rank_address := 0;
1003 IF NEW.rank_search > 30 THEN
1004 NEW.rank_search := 30;
1007 IF NEW.rank_address > 30 THEN
1008 NEW.rank_address := 30;
1011 IF (NEW.extratags -> 'capital') = 'yes' THEN
1012 NEW.rank_search := NEW.rank_search - 1;
1015 -- a country code make no sense below rank 4 (country)
1016 IF NEW.rank_search < 4 THEN
1017 NEW.calculated_country_code := NULL;
1020 -- Block import below rank 22
1021 -- IF NEW.rank_search > 22 THEN
1025 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1027 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1029 IF NEW.rank_address > 0 THEN
1030 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1031 -- Performance: We just can't handle re-indexing for country level changes
1032 IF st_area(NEW.geometry) < 1 THEN
1033 -- mark items within the geometry for re-indexing
1034 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1036 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1037 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1038 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));
1039 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1040 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));
1043 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1045 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1046 IF NEW.type='postcode' THEN
1048 ELSEIF NEW.rank_search < 16 THEN
1050 ELSEIF NEW.rank_search < 18 THEN
1052 ELSEIF NEW.rank_search < 20 THEN
1054 ELSEIF NEW.rank_search = 21 THEN
1056 ELSEIF NEW.rank_search < 24 THEN
1058 ELSEIF NEW.rank_search < 26 THEN
1059 diameter := 0.002; -- 100 to 200 meters
1060 ELSEIF NEW.rank_search < 28 THEN
1061 diameter := 0.001; -- 50 to 100 meters
1063 IF diameter > 0 THEN
1064 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1065 IF NEW.rank_search >= 26 THEN
1066 -- roads may cause reparenting for >27 rank places
1067 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1068 ELSEIF NEW.rank_search >= 16 THEN
1069 -- up to rank 16, street-less addresses may need reparenting
1070 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);
1072 -- for all other places the search terms may change as well
1073 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);
1080 -- add to tables for special search
1081 -- Note: won't work on initial import because the classtype tables
1082 -- do not yet exist. It won't hurt either.
1083 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1084 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1086 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1087 USING NEW.place_id, ST_Centroid(NEW.geometry);
1096 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1101 place_centroid GEOMETRY;
1103 search_maxdistance FLOAT[];
1104 search_mindistance FLOAT[];
1105 address_havelevel BOOLEAN[];
1112 relation_members TEXT[];
1114 linkedplacex RECORD;
1115 search_diameter FLOAT;
1116 search_prevdiameter FLOAT;
1117 search_maxrank INTEGER;
1118 address_maxrank INTEGER;
1119 address_street_word_id INTEGER;
1120 address_street_word_ids INTEGER[];
1121 parent_place_id_rank BIGINT;
1126 location_rank_search INTEGER;
1127 location_distance FLOAT;
1128 location_parent GEOMETRY;
1129 location_isaddress BOOLEAN;
1130 location_keywords INTEGER[];
1132 default_language TEXT;
1133 name_vector INTEGER[];
1134 nameaddress_vector INTEGER[];
1136 linked_node_id BIGINT;
1142 IF OLD.indexed_status = 100 THEN
1143 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1144 delete from placex where place_id = OLD.place_id;
1148 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1152 -- ignore interpolated addresses
1153 IF NEW.class = 'place' and NEW.type = 'address' THEN
1157 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1159 --RAISE WARNING '%',NEW.place_id;
1160 --RAISE WARNING '%', NEW;
1162 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1163 -- Silently do nothing
1167 -- TODO: this test is now redundant?
1168 IF OLD.indexed_status != 0 THEN
1170 NEW.indexed_date = now();
1172 result := deleteSearchName(NEW.partition, NEW.place_id);
1173 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1174 result := deleteRoad(NEW.partition, NEW.place_id);
1175 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1176 UPDATE placex set linked_place_id = null, indexed_status = 2
1177 where linked_place_id = NEW.place_id;
1179 IF NEW.linked_place_id is not null THEN
1183 -- Speed up searches - just use the centroid of the feature
1184 -- cheaper but less acurate
1185 place_centroid := ST_PointOnSurface(NEW.geometry);
1186 NEW.centroid := null;
1188 -- recalculate country and partition
1189 IF NEW.rank_search = 4 THEN
1190 -- for countries, believe the mapped country code,
1191 -- so that we remain in the right partition if the boundaries
1193 NEW.partition := get_partition(lower(NEW.country_code));
1194 IF NEW.partition = 0 THEN
1195 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1196 NEW.partition := get_partition(NEW.calculated_country_code);
1198 NEW.calculated_country_code := lower(NEW.country_code);
1201 IF NEW.rank_search > 4 THEN
1202 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1203 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1205 NEW.calculated_country_code := NULL;
1207 NEW.partition := get_partition(NEW.calculated_country_code);
1209 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1212 IF NEW.class = 'place' AND NEW.type = 'houses'THEN
1213 IF NEW.osm_type = 'W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1214 NEW.parent_place_id := get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1215 NEW.partition, place_centroid, NEW.geometry);
1216 i := create_interpolation(NEW.osm_id, NEW.housenumber, NEW.parent_place_id,
1217 NEW.partition, NEW.calculated_country_code,
1218 NEW.geometry_sector, NEW.postcode, NEW.geometry);
1223 -- waterway ways are linked when they are part of a relation and have the same class/type
1224 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1225 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1227 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1228 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1229 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1230 FOR linked_node_id IN SELECT place_id FROM placex
1231 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1232 and class = NEW.class and type = NEW.type
1233 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1235 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1242 -- Adding ourselves to the list simplifies address calculations later
1243 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1245 -- What level are we searching from
1246 search_maxrank := NEW.rank_search;
1248 -- Thought this wasn't needed but when we add new languages to the country_name table
1249 -- we need to update the existing names
1250 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1251 default_language := get_country_language_code(NEW.calculated_country_code);
1252 IF default_language IS NOT NULL THEN
1253 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1254 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1255 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1256 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1261 -- Initialise the name vector using our name
1262 name_vector := make_keywords(NEW.name);
1263 nameaddress_vector := '{}'::int[];
1266 address_havelevel[i] := false;
1269 NEW.importance := null;
1270 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1271 IF NEW.importance IS NULL THEN
1272 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;
1275 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1277 -- For low level elements we inherit from our parent road
1278 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1280 --RAISE WARNING 'finding street for %', NEW;
1282 -- We won't get a better centroid, besides these places are too small to care
1283 NEW.centroid := place_centroid;
1285 NEW.parent_place_id := null;
1287 -- if we have a POI and there is no address information,
1288 -- see if we can get it from a surrounding building
1289 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1290 AND NEW.housenumber IS NULL THEN
1291 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1292 and (housenumber is not null or street is not null or addr_place is not null)
1293 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1296 NEW.housenumber := location.housenumber;
1297 NEW.street := location.street;
1298 NEW.addr_place := location.addr_place;
1302 -- We have to find our parent road.
1303 -- Copy data from linked items (points on ways, addr:street links, relations)
1305 -- Is this object part of a relation?
1306 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1308 -- At the moment we only process one type of relation - associatedStreet
1309 IF relation.tags @> ARRAY['associatedStreet'] THEN
1310 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1311 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1312 --RAISE WARNING 'node in relation %',relation;
1313 SELECT place_id from placex where osm_type = 'W'
1314 and osm_id = substring(relation.members[i],2,200)::bigint
1315 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1322 -- Note that addr:street links can only be indexed once the street itself is indexed
1323 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1324 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1325 IF address_street_word_ids IS NOT NULL THEN
1326 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1327 NEW.parent_place_id := location.place_id;
1332 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1333 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1334 IF address_street_word_ids IS NOT NULL THEN
1335 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1336 NEW.parent_place_id := location.place_id;
1341 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1343 --RAISE WARNING 'x1';
1344 -- Is this node part of a way?
1345 FOR location IN select p.* from placex p, planet_osm_ways w
1346 where p.osm_type = 'W' and p.rank_search >= 26
1347 and p.geometry && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes)
1349 --RAISE WARNING '%', location;
1350 -- Way IS a road then we are on it - that must be our road
1351 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1352 --RAISE WARNING 'node in way that is a street %',location;
1353 NEW.parent_place_id := location.place_id;
1356 -- If this way is a street interpolation line then it is probably as good as we are going to get
1357 IF NEW.parent_place_id IS NULL AND location.class = 'place' and location.type='houses' THEN
1358 NEW.parent_place_id := location.parent_place_id;
1361 -- Is the WAY part of a relation
1362 IF NEW.parent_place_id IS NULL THEN
1363 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1365 -- At the moment we only process one type of relation - associatedStreet
1366 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1367 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1368 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1369 --RAISE WARNING 'node in way that is in a relation %',relation;
1370 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1371 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1378 -- If the way mentions a street or place address, try that for parenting.
1379 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1380 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1381 IF address_street_word_ids IS NOT NULL THEN
1382 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1383 NEW.parent_place_id := linkedplacex.place_id;
1388 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1389 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1390 IF address_street_word_ids IS NOT NULL THEN
1391 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1392 NEW.parent_place_id := linkedplacex.place_id;
1401 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1402 -- Still nothing, just use the nearest road
1403 IF NEW.parent_place_id IS NULL THEN
1404 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1405 NEW.parent_place_id := location.place_id;
1410 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1412 -- If we didn't find any road fallback to standard method
1413 IF NEW.parent_place_id IS NOT NULL THEN
1415 -- Get the details of the parent road
1416 select * from search_name where place_id = NEW.parent_place_id INTO location;
1417 NEW.calculated_country_code := location.country_code;
1419 -- Merge the postcode into the parent's address if necessary XXXX
1420 IF NEW.postcode IS NOT NULL THEN
1421 isin_tokens := '{}'::int[];
1422 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1423 IF address_street_word_id is not null
1424 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1425 isin_tokens := isin_tokens || address_street_word_id;
1427 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1428 IF address_street_word_id is not null
1429 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1430 isin_tokens := isin_tokens || address_street_word_id;
1432 IF isin_tokens != '{}'::int[] THEN
1434 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1435 WHERE place_id = NEW.parent_place_id;
1439 --RAISE WARNING '%', NEW.name;
1440 -- If there is no name it isn't searchable, don't bother to create a search record
1441 IF NEW.name is NULL THEN
1445 -- Merge address from parent
1446 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1447 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1449 -- Performance, it would be more acurate to do all the rest of the import
1450 -- process but it takes too long
1451 -- Just be happy with inheriting from parent road only
1453 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1454 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1457 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);
1464 -- RAISE WARNING ' INDEXING Started:';
1465 -- RAISE WARNING ' INDEXING: %',NEW;
1467 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1469 -- see if we have any special relation members
1470 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1472 -- RAISE WARNING 'get_osm_rel_members, label';
1473 IF relation_members IS NOT NULL THEN
1474 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1476 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1477 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1479 -- If we don't already have one use this as the centre point of the geometry
1480 IF NEW.centroid IS NULL THEN
1481 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1484 -- merge in the label name, re-init word vector
1485 IF NOT linkedPlacex.name IS NULL THEN
1486 NEW.name := linkedPlacex.name || NEW.name;
1487 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1490 -- merge in extra tags
1491 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1493 -- mark the linked place (excludes from search results)
1494 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1496 -- keep a note of the node id in case we need it for wikipedia in a bit
1497 linked_node_id := linkedPlacex.osm_id;
1502 IF NEW.centroid IS NULL THEN
1504 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1506 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1507 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1509 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1510 -- But that can be fixed by explicitly setting the label in the data
1511 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1512 AND NEW.rank_address = linkedPlacex.rank_address THEN
1514 -- If we don't already have one use this as the centre point of the geometry
1515 IF NEW.centroid IS NULL THEN
1516 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1519 -- merge in the name, re-init word vector
1520 IF NOT linkedPlacex.name IS NULL THEN
1521 NEW.name := linkedPlacex.name || NEW.name;
1522 name_vector := make_keywords(NEW.name);
1525 -- merge in extra tags
1526 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1528 -- mark the linked place (excludes from search results)
1529 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1531 -- keep a note of the node id in case we need it for wikipedia in a bit
1532 linked_node_id := linkedPlacex.osm_id;
1544 -- Name searches can be done for ways as well as relations
1545 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1547 -- not found one yet? how about doing a name search
1548 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1550 FOR linkedPlacex IN select placex.* from placex WHERE
1551 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1552 AND placex.rank_address = NEW.rank_address
1553 AND placex.place_id != NEW.place_id
1554 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1555 AND st_covers(NEW.geometry, placex.geometry)
1558 -- If we don't already have one use this as the centre point of the geometry
1559 IF NEW.centroid IS NULL THEN
1560 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1563 -- merge in the name, re-init word vector
1564 NEW.name := linkedPlacex.name || NEW.name;
1565 name_vector := make_keywords(NEW.name);
1567 -- merge in extra tags
1568 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1570 -- mark the linked place (excludes from search results)
1571 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1573 -- keep a note of the node id in case we need it for wikipedia in a bit
1574 linked_node_id := linkedPlacex.osm_id;
1578 IF NEW.centroid IS NOT NULL THEN
1579 place_centroid := NEW.centroid;
1580 -- Place might have had only a name tag before but has now received translations
1581 -- from the linked place. Make sure a name tag for the default language exists in
1583 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1584 default_language := get_country_language_code(NEW.calculated_country_code);
1585 IF default_language IS NOT NULL THEN
1586 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1587 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1588 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1589 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1595 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1596 IF NEW.importance is null THEN
1597 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1599 -- Still null? how about looking it up by the node id
1600 IF NEW.importance IS NULL THEN
1601 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;
1606 -- make sure all names are in the word table
1607 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1608 perform create_country(NEW.name, lower(NEW.country_code));
1611 NEW.parent_place_id = 0;
1612 parent_place_id_rank = 0;
1614 -- convert isin to array of tokenids
1615 isin_tokens := '{}'::int[];
1616 IF NEW.isin IS NOT NULL THEN
1617 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1618 IF array_upper(isin, 1) IS NOT NULL THEN
1619 FOR i IN 1..array_upper(isin, 1) LOOP
1620 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1621 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1622 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1623 isin_tokens := isin_tokens || address_street_word_id;
1626 -- merge word into address vector
1627 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1628 IF address_street_word_id IS NOT NULL THEN
1629 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1634 IF NEW.postcode IS NOT NULL THEN
1635 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1636 IF array_upper(isin, 1) IS NOT NULL THEN
1637 FOR i IN 1..array_upper(isin, 1) LOOP
1638 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1639 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1640 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1641 isin_tokens := isin_tokens || address_street_word_id;
1644 -- merge into address vector
1645 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1646 IF address_street_word_id IS NOT NULL THEN
1647 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1653 -- for the USA we have an additional address table. Merge in zip codes from there too
1654 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1655 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1656 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1657 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1658 isin_tokens := isin_tokens || address_street_word_id;
1660 -- also merge in the single word version
1661 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1662 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1666 -- RAISE WARNING 'ISIN: %', isin_tokens;
1668 -- Process area matches
1669 location_rank_search := 0;
1670 location_distance := 0;
1671 location_parent := NULL;
1672 -- added ourself as address already
1673 address_havelevel[NEW.rank_address] := true;
1674 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1675 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1677 --RAISE WARNING ' AREA: %',location;
1679 IF location.rank_address != location_rank_search THEN
1680 location_rank_search := location.rank_address;
1681 IF location.isguess THEN
1682 location_distance := location.distance * 1.5;
1684 IF location.rank_address <= 12 THEN
1685 -- for county and above, if we have an area consider that exact
1686 -- (It would be nice to relax the constraint for places close to
1687 -- the boundary but we'd need the exact geometry for that. Too
1689 location_distance = 0;
1691 -- Below county level remain slightly fuzzy.
1692 location_distance := location.distance * 0.5;
1696 CONTINUE WHEN location.keywords <@ location_keywords;
1699 IF location.distance < location_distance OR NOT location.isguess THEN
1700 location_keywords := location.keywords;
1702 location_isaddress := NOT address_havelevel[location.rank_address];
1703 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1704 location_isaddress := ST_Contains(location_parent,location.centroid);
1707 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1708 -- Add it to the list of search terms
1709 IF location.rank_search > 4 THEN
1710 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1712 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1714 IF location_isaddress THEN
1716 address_havelevel[location.rank_address] := true;
1717 IF NOT location.isguess THEN
1718 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1721 IF location.rank_address > parent_place_id_rank THEN
1722 NEW.parent_place_id = location.place_id;
1723 parent_place_id_rank = location.rank_address;
1728 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1734 -- try using the isin value to find parent places
1735 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1736 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1737 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1738 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1740 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1742 --RAISE WARNING ' ISIN: %',location;
1744 IF location.rank_search > 4 THEN
1745 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1746 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1747 address_havelevel[location.rank_address] := true;
1749 IF location.rank_address > parent_place_id_rank THEN
1750 NEW.parent_place_id = location.place_id;
1751 parent_place_id_rank = location.rank_address;
1761 -- for long ways we should add search terms for the entire length
1762 IF st_length(NEW.geometry) > 0.05 THEN
1764 location_rank_search := 0;
1765 location_distance := 0;
1767 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1769 IF location.rank_address != location_rank_search THEN
1770 location_rank_search := location.rank_address;
1771 location_distance := location.distance * 1.5;
1774 IF location.rank_search > 4 AND location.distance < location_distance THEN
1776 -- Add it to the list of search terms
1777 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1778 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1786 -- if we have a name add this to the name search table
1787 IF NEW.name IS NOT NULL THEN
1789 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1790 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1793 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1794 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1797 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);
1801 -- If we've not managed to pick up a better one - default centroid
1802 IF NEW.centroid IS NULL THEN
1803 NEW.centroid := place_centroid;
1813 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1819 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1821 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1822 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1823 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1824 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1826 IF OLD.rank_address < 30 THEN
1828 -- mark everything linked to this place for re-indexing
1829 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1830 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1831 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1833 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1834 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1836 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1837 b := deleteRoad(OLD.partition, OLD.place_id);
1839 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1840 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1841 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1845 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1847 IF OLD.rank_address < 26 THEN
1848 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1851 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1853 IF OLD.name is not null THEN
1854 b := deleteSearchName(OLD.partition, OLD.place_id);
1857 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1859 DELETE FROM place_addressline where place_id = OLD.place_id;
1861 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1863 -- remove from tables for special search
1864 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1865 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1867 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1870 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1878 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1884 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1886 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1887 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1888 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;
1890 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1896 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;
1898 -- interpolations are special
1899 IF OLD.class = 'place' and OLD.type = 'houses' THEN
1900 UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = 'place' and type = 'address';
1909 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1914 existingplacex RECORD;
1915 existinggeometry GEOMETRY;
1916 existingplace_id BIGINT;
1921 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1922 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1924 IF FALSE and NEW.osm_type = 'R' THEN
1925 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;
1926 --DEBUG: RAISE WARNING '%', existingplacex;
1929 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
1930 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1931 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1932 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1936 -- Patch in additional country names
1937 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1938 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1941 -- Have we already done this place?
1942 select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
1944 -- Get the existing place_id
1945 select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex;
1947 -- Handle a place changing type by removing the old data
1948 -- My generated 'place' types are causing havok because they overlap with real keys
1949 -- TODO: move them to their own special purpose key/class to avoid collisions
1950 IF existing.osm_type IS NULL THEN
1951 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1954 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1955 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1958 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1959 AND st_area(existing.geometry) > 0.02
1960 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1961 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1963 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1964 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1968 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1969 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1971 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
1972 IF existingplacex.osm_type IS NULL OR
1973 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
1976 IF existingplacex.osm_type IS NOT NULL THEN
1977 -- sanity check: ignore admin_level changes on places with too many active children
1978 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
1979 --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;
1980 --LIMIT INDEXING: IF i > 100000 THEN
1981 --LIMIT INDEXING: RETURN null;
1982 --LIMIT INDEXING: END IF;
1985 IF existing.osm_type IS NOT NULL THEN
1986 -- pathological case caused by the triggerless copy into place during initial import
1987 -- force delete even for large areas, it will be reinserted later
1988 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;
1989 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1992 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1993 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1994 street, addr_place, isin, postcode, country_code, extratags, geometry)
1995 values (NEW.osm_type
2011 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2016 -- Various ways to do the update
2018 -- Debug, what's changed?
2020 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2021 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2023 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2024 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2026 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2027 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2029 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2030 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2032 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2033 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2035 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2036 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2038 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2039 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2043 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2044 IF existing.geometry::text != NEW.geometry::text
2045 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2046 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2049 -- Get the version of the geometry actually used (in placex table)
2050 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;
2052 -- Performance limit
2053 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2055 -- 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
2056 update placex set indexed_status = 2 where indexed_status = 0 and
2057 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2058 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2059 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2061 update placex set indexed_status = 2 where indexed_status = 0 and
2062 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2063 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2064 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2071 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2072 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2073 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2074 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2075 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2076 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2077 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2078 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2079 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2080 OR existing.geometry::text != NEW.geometry::text
2085 housenumber = NEW.housenumber,
2086 street = NEW.street,
2087 addr_place = NEW.addr_place,
2089 postcode = NEW.postcode,
2090 country_code = NEW.country_code,
2091 extratags = NEW.extratags,
2092 admin_level = NEW.admin_level,
2093 geometry = NEW.geometry
2094 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2096 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2097 IF NEW.postcode IS NULL THEN
2098 -- postcode was deleted, no longer retain in placex
2099 DELETE FROM placex where place_id = existingplacex.place_id;
2103 NEW.name := hstore('ref', NEW.postcode);
2108 housenumber = NEW.housenumber,
2109 street = NEW.street,
2110 addr_place = NEW.addr_place,
2112 postcode = NEW.postcode,
2113 country_code = NEW.country_code,
2114 parent_place_id = null,
2115 extratags = NEW.extratags,
2116 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2118 geometry = NEW.geometry
2119 where place_id = existingplacex.place_id;
2123 -- for interpolations invalidate all nodes on the line
2124 IF NEW.class = 'place' and NEW.type = 'houses' and NEW.osm_type = 'W' THEN
2125 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);
2128 -- Abort the add (we modified the existing place instead)
2132 $$ LANGUAGE plpgsql;
2135 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2140 IF name is null THEN
2144 FOR j IN 1..array_upper(languagepref,1) LOOP
2145 IF name ? languagepref[j] THEN
2146 result := trim(name->languagepref[j]);
2147 IF result != '' THEN
2153 -- anything will do as a fallback - just take the first name type thing there is
2154 RETURN trim((avals(name))[1]);
2157 LANGUAGE plpgsql IMMUTABLE;
2160 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2171 search := ARRAY['ref'];
2174 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2177 select rank_address,name,distance,length(name::text) as namelength
2178 from place_addressline join placex on (address_place_id = placex.place_id)
2179 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2180 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2182 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2183 FOR j IN 1..array_upper(search, 1) LOOP
2184 FOR k IN 1..array_upper(location.name, 1) LOOP
2185 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
2186 result[(100 - location.rank_address)] := trim(location.name[k].value);
2187 found := location.rank_address;
2194 RETURN array_to_string(result,', ');
2199 --housenumber only needed for tiger data
2200 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2212 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2213 currresult := trim(get_name_by_language(location.name, languagepref));
2214 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2215 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2216 prevresult := currresult;
2220 RETURN array_to_string(result,', ');
2225 DROP TYPE IF EXISTS addressline CASCADE;
2226 create type addressline as (
2233 admin_level INTEGER,
2236 rank_address INTEGER,
2240 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2243 for_place_id BIGINT;--parent_place_id
2248 countrylocation RECORD;
2249 searchcountrycode varchar(2);
2250 searchhousenumber TEXT;
2251 searchhousename HSTORE;
2252 searchrankaddress INTEGER;
2253 searchpostcode TEXT;
2259 --first query tiger data
2260 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2261 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2262 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2263 IF for_place_id IS NOT NULL THEN
2264 searchhousenumber = in_housenumber::text;
2267 IF for_place_id IS NULL THEN
2268 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2269 WHERE place_id = in_place_id
2270 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2273 IF for_place_id IS NULL THEN
2274 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2275 WHERE place_id = in_place_id and rank_address = 30
2276 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2279 IF for_place_id IS NULL THEN
2280 select coalesce(linked_place_id, place_id), calculated_country_code,
2281 housenumber, rank_search, postcode, null
2282 from placex where place_id = in_place_id
2283 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2286 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2289 hadcountry := false;
2291 select placex.place_id, osm_type, osm_id,
2292 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2293 class, type, admin_level, true as fromarea, true as isaddress,
2294 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2295 0 as distance, calculated_country_code, postcode
2297 where place_id = for_place_id
2299 --RAISE WARNING '%',location;
2300 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2301 searchcountrycode := location.calculated_country_code;
2303 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2304 location.isaddress := FALSE;
2306 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2307 searchpostcode := location.postcode;
2309 IF location.rank_address = 4 AND location.isaddress THEN
2312 IF location.rank_address < 4 AND NOT hadcountry THEN
2313 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2314 IF countryname IS NOT NULL THEN
2315 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2316 RETURN NEXT countrylocation;
2319 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2320 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2321 location.distance)::addressline;
2322 RETURN NEXT countrylocation;
2323 found := location.rank_address;
2327 select placex.place_id, osm_type, osm_id,
2328 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2329 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2330 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2331 admin_level, fromarea, isaddress,
2332 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,
2333 distance,calculated_country_code,postcode
2334 from place_addressline join placex on (address_place_id = placex.place_id)
2335 where place_addressline.place_id = for_place_id
2336 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2337 and address_place_id != for_place_id
2338 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2339 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2341 --RAISE WARNING '%',location;
2342 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2343 searchcountrycode := location.calculated_country_code;
2345 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2346 location.isaddress := FALSE;
2348 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2349 searchpostcode := location.postcode;
2351 IF location.rank_address = 4 AND location.isaddress THEN
2354 IF location.rank_address < 4 AND NOT hadcountry THEN
2355 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2356 IF countryname IS NOT NULL THEN
2357 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2358 RETURN NEXT countrylocation;
2361 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2362 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2363 location.distance)::addressline;
2364 RETURN NEXT countrylocation;
2365 found := location.rank_address;
2369 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2370 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2371 IF countryname IS NOT NULL THEN
2372 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2373 RETURN NEXT location;
2377 IF searchcountrycode IS NOT NULL THEN
2378 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2379 RETURN NEXT location;
2382 IF searchhousename IS NOT NULL THEN
2383 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2384 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2385 RETURN NEXT location;
2388 IF searchhousenumber IS NOT NULL THEN
2389 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2390 RETURN NEXT location;
2393 IF searchpostcode IS NOT NULL THEN
2394 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2395 RETURN NEXT location;
2404 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2407 numfeatures integer;
2411 housenumber = place.housenumber,
2412 street = place.street,
2413 addr_place = place.addr_place,
2415 postcode = place.postcode,
2416 country_code = place.country_code,
2417 parent_place_id = null
2419 where placex.place_id = search_place_id
2420 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2421 and place.class = placex.class and place.type = placex.type;
2422 update placex set indexed_status = 2 where place_id = search_place_id;
2423 update placex set indexed_status = 0 where place_id = search_place_id;
2429 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2435 ELSEIF rank < 4 THEN
2437 ELSEIF rank < 8 THEN
2439 ELSEIF rank < 12 THEN
2441 ELSEIF rank < 16 THEN
2443 ELSEIF rank = 16 THEN
2445 ELSEIF rank = 17 THEN
2446 RETURN 'Town / Island';
2447 ELSEIF rank = 18 THEN
2448 RETURN 'Village / Hamlet';
2449 ELSEIF rank = 20 THEN
2451 ELSEIF rank = 21 THEN
2452 RETURN 'Postcode Area';
2453 ELSEIF rank = 22 THEN
2454 RETURN 'Croft / Farm / Locality / Islet';
2455 ELSEIF rank = 23 THEN
2456 RETURN 'Postcode Area';
2457 ELSEIF rank = 25 THEN
2458 RETURN 'Postcode Point';
2459 ELSEIF rank = 26 THEN
2460 RETURN 'Street / Major Landmark';
2461 ELSEIF rank = 27 THEN
2462 RETURN 'Minory Street / Path';
2463 ELSEIF rank = 28 THEN
2464 RETURN 'House / Building';
2466 RETURN 'Other: '||rank;
2473 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2479 ELSEIF rank < 2 THEN
2481 ELSEIF rank < 4 THEN
2483 ELSEIF rank = 5 THEN
2485 ELSEIF rank < 8 THEN
2487 ELSEIF rank < 12 THEN
2489 ELSEIF rank < 16 THEN
2491 ELSEIF rank = 16 THEN
2493 ELSEIF rank = 17 THEN
2494 RETURN 'Town / Village / Hamlet';
2495 ELSEIF rank = 20 THEN
2497 ELSEIF rank = 21 THEN
2498 RETURN 'Postcode Area';
2499 ELSEIF rank = 22 THEN
2500 RETURN 'Croft / Farm / Locality / Islet';
2501 ELSEIF rank = 23 THEN
2502 RETURN 'Postcode Area';
2503 ELSEIF rank = 25 THEN
2504 RETURN 'Postcode Point';
2505 ELSEIF rank = 26 THEN
2506 RETURN 'Street / Major Landmark';
2507 ELSEIF rank = 27 THEN
2508 RETURN 'Minory Street / Path';
2509 ELSEIF rank = 28 THEN
2510 RETURN 'House / Building';
2512 RETURN 'Other: '||rank;
2519 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2520 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2525 place_centroid GEOMETRY;
2526 out_partition INTEGER;
2527 out_parent_place_id BIGINT;
2529 address_street_word_id INTEGER;
2534 place_centroid := ST_Centroid(pointgeo);
2535 out_partition := get_partition(in_countrycode);
2536 out_parent_place_id := null;
2538 address_street_word_id := get_name_id(make_standard_name(in_street));
2539 IF address_street_word_id IS NOT NULL THEN
2540 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2541 out_parent_place_id := location.place_id;
2545 IF out_parent_place_id IS NULL THEN
2546 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2547 out_parent_place_id := location.place_id;
2551 out_postcode := in_postcode;
2552 IF out_postcode IS NULL THEN
2553 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2555 IF out_postcode IS NULL THEN
2556 out_postcode := getNearestPostcode(out_partition, place_centroid);
2560 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2561 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2562 newpoints := newpoints + 1;
2569 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2576 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2577 IF members[i+1] = member THEN
2578 result := result || members[i];
2587 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2593 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2594 IF members[i+1] = ANY(memberLabels) THEN
2595 RETURN NEXT members[i];
2604 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2605 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2607 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2608 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
2609 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2610 ), '') AS bytea), 'UTF8');
2612 LANGUAGE SQL IMMUTABLE STRICT;
2614 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2618 RETURN decode_url_part(p);
2620 WHEN others THEN return null;
2623 LANGUAGE plpgsql IMMUTABLE;
2625 DROP TYPE wikipedia_article_match CASCADE;
2626 create type wikipedia_article_match as (
2632 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2638 wiki_article_title TEXT;
2639 wiki_article_language TEXT;
2640 result wikipedia_article_match;
2642 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'];
2644 WHILE langs[i] IS NOT NULL LOOP
2645 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2646 IF wiki_article is not null THEN
2647 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2648 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2649 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2650 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2651 wiki_article := replace(wiki_article,' ','_');
2652 IF strpos(wiki_article, ':') IN (3,4) THEN
2653 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2654 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2656 wiki_article_title := trim(wiki_article);
2657 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;
2660 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2661 from wikipedia_article
2662 where language = wiki_article_language and
2663 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2665 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2666 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2667 where wikipedia_redirect.language = wiki_article_language and
2668 (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'\\',''))
2669 order by importance desc limit 1 INTO result;
2671 IF result.language is not null THEN
2682 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2683 RETURNS SETOF GEOMETRY
2697 remainingdepth INTEGER;
2702 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2704 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2705 RETURN NEXT geometry;
2709 remainingdepth := maxdepth - 1;
2710 area := ST_AREA(geometry);
2711 IF remainingdepth < 1 OR area < maxarea THEN
2712 RETURN NEXT geometry;
2716 xmin := st_xmin(geometry);
2717 xmax := st_xmax(geometry);
2718 ymin := st_ymin(geometry);
2719 ymax := st_ymax(geometry);
2720 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2722 -- if the geometry completely covers the box don't bother to slice any more
2723 IF ST_AREA(secbox) = area THEN
2724 RETURN NEXT geometry;
2728 xmid := (xmin+xmax)/2;
2729 ymid := (ymin+ymax)/2;
2732 FOR seg IN 1..4 LOOP
2735 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2738 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2741 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2744 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2747 IF st_intersects(geometry, secbox) THEN
2748 secgeo := st_intersection(geometry, secbox);
2749 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2750 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2751 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2753 RETURN NEXT geo.geom;
2765 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2766 RETURNS SETOF GEOMETRY
2771 -- 10000000000 is ~~ 1x1 degree
2772 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2773 RETURN NEXT geo.geom;
2781 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2785 osmtype character(1);
2789 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2790 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2791 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2792 -- force delete from place/placex by making it a very small geometry
2793 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;
2794 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2801 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2809 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2810 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2811 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2812 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2813 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2814 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2815 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));
2816 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2817 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));
2823 ELSEIF rank < 18 THEN
2825 ELSEIF rank < 20 THEN
2827 ELSEIF rank = 21 THEN
2829 ELSEIF rank < 24 THEN
2831 ELSEIF rank < 26 THEN
2832 diameter := 0.002; -- 100 to 200 meters
2833 ELSEIF rank < 28 THEN
2834 diameter := 0.001; -- 50 to 100 meters
2836 IF diameter > 0 THEN
2838 -- roads may cause reparenting for >27 rank places
2839 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2840 ELSEIF rank >= 16 THEN
2841 -- up to rank 16, street-less addresses may need reparenting
2842 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);
2844 -- for all other places the search terms may change as well
2845 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);