1 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
6 -- RAISE WARNING '%',place;
7 NEWgeometry := ST_PointOnSurface(place);
8 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
11 LANGUAGE plpgsql IMMUTABLE;
13 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
14 AS '{modulepath}/nominatim.so', 'transliteration'
15 LANGUAGE c IMMUTABLE STRICT;
17 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
18 AS '{modulepath}/nominatim.so', 'gettokenstring'
19 LANGUAGE c IMMUTABLE STRICT;
21 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
26 o := gettokenstring(transliteration(name));
27 RETURN trim(substr(o,1,length(o)));
30 LANGUAGE 'plpgsql' IMMUTABLE;
32 -- returns NULL if the word is too common
33 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
38 return_word_id INTEGER;
41 lookup_token := trim(lookup_word);
42 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;
43 IF return_word_id IS NULL THEN
44 return_word_id := nextval('seq_word');
45 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
47 IF count > get_maxwordfreq() THEN
48 return_word_id := NULL;
51 RETURN return_word_id;
56 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
61 return_word_id INTEGER;
63 lookup_token := ' '||trim(lookup_word);
64 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
65 IF return_word_id IS NULL THEN
66 return_word_id := nextval('seq_word');
67 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
69 RETURN return_word_id;
74 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
79 return_word_id INTEGER;
81 lookup_token := ' '||trim(lookup_word);
82 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
83 IF return_word_id IS NULL THEN
84 return_word_id := nextval('seq_word');
85 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
87 RETURN return_word_id;
92 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
97 return_word_id INTEGER;
99 lookup_token := ' '||trim(lookup_word);
100 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
101 IF return_word_id IS NULL THEN
102 return_word_id := nextval('seq_word');
103 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
105 RETURN return_word_id;
110 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
115 return_word_id INTEGER;
117 lookup_token := ' '||trim(lookup_word);
118 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;
119 IF return_word_id IS NULL THEN
120 return_word_id := nextval('seq_word');
121 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
123 RETURN return_word_id;
128 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
133 nospace_lookup_token TEXT;
134 return_word_id INTEGER;
136 lookup_token := ' '||trim(lookup_word);
137 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
138 IF return_word_id IS NULL THEN
139 return_word_id := nextval('seq_word');
140 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
141 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
142 -- IF ' '||nospace_lookup_token != lookup_token THEN
143 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
146 RETURN return_word_id;
151 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
156 RETURN getorcreate_name_id(lookup_word, '');
161 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
166 return_word_id INTEGER;
168 lookup_token := trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 RETURN return_word_id;
173 LANGUAGE plpgsql IMMUTABLE;
175 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
180 return_word_id INTEGER;
182 lookup_token := ' '||trim(lookup_word);
183 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
184 RETURN return_word_id;
187 LANGUAGE plpgsql IMMUTABLE;
189 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
194 return_word_ids INTEGER[];
196 lookup_token := ' '||trim(lookup_word);
197 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
198 RETURN return_word_ids;
201 LANGUAGE plpgsql IMMUTABLE;
203 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
210 IF array_upper(a, 1) IS NULL THEN
213 IF array_upper(b, 1) IS NULL THEN
217 FOR i IN 1..array_upper(b, 1) LOOP
218 IF NOT (ARRAY[b[i]] <@ r) THEN
225 LANGUAGE plpgsql IMMUTABLE;
227 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
236 FOR item IN SELECT (each(src)).* LOOP
238 s := make_standard_name(item.value);
239 w := getorcreate_country(s, lookup_country_code);
241 words := regexp_split_to_array(item.value, E'[,;()]');
242 IF array_upper(words, 1) != 1 THEN
243 FOR j IN 1..array_upper(words, 1) LOOP
244 s := make_standard_name(words[j]);
246 w := getorcreate_country(s, lookup_country_code);
255 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
265 result := '{}'::INTEGER[];
267 FOR item IN SELECT (each(src)).* LOOP
269 s := make_standard_name(item.value);
271 w := getorcreate_name_id(s, item.value);
273 IF not(ARRAY[w] <@ result) THEN
274 result := result || w;
277 w := getorcreate_word_id(s);
279 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
280 result := result || w;
283 words := string_to_array(s, ' ');
284 IF array_upper(words, 1) IS NOT NULL THEN
285 FOR j IN 1..array_upper(words, 1) LOOP
286 IF (words[j] != '') THEN
287 w = getorcreate_word_id(words[j]);
288 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
289 result := result || w;
295 words := regexp_split_to_array(item.value, E'[,;()]');
296 IF array_upper(words, 1) != 1 THEN
297 FOR j IN 1..array_upper(words, 1) LOOP
298 s := make_standard_name(words[j]);
300 w := getorcreate_word_id(s);
301 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
302 result := result || w;
308 s := regexp_replace(item.value, '市$', '');
309 IF s != item.value THEN
310 s := make_standard_name(s);
312 w := getorcreate_name_id(s, item.value);
313 IF NOT (ARRAY[w] <@ result) THEN
314 result := result || w;
324 LANGUAGE plpgsql IMMUTABLE;
326 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
336 result := '{}'::INTEGER[];
338 s := make_standard_name(src);
339 w := getorcreate_name_id(s, src);
341 IF NOT (ARRAY[w] <@ result) THEN
342 result := result || w;
345 w := getorcreate_word_id(s);
347 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
348 result := result || w;
351 words := string_to_array(s, ' ');
352 IF array_upper(words, 1) IS NOT NULL THEN
353 FOR j IN 1..array_upper(words, 1) LOOP
354 IF (words[j] != '') THEN
355 w = getorcreate_word_id(words[j]);
356 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
357 result := result || w;
363 words := regexp_split_to_array(src, E'[,;()]');
364 IF array_upper(words, 1) != 1 THEN
365 FOR j IN 1..array_upper(words, 1) LOOP
366 s := make_standard_name(words[j]);
368 w := getorcreate_word_id(s);
369 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
370 result := result || w;
376 s := regexp_replace(src, '市$', '');
378 s := make_standard_name(s);
380 w := getorcreate_name_id(s, src);
381 IF NOT (ARRAY[w] <@ result) THEN
382 result := result || w;
390 LANGUAGE plpgsql IMMUTABLE;
392 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
395 place_centre GEOMETRY;
398 place_centre := ST_PointOnSurface(place);
400 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
402 -- Try for a OSM polygon
403 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
405 RETURN nearcountry.country_code;
408 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
410 -- Try for OSM fallback data
411 -- The order is to deal with places like HongKong that are 'states' within another polygon
412 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
414 RETURN nearcountry.country_code;
417 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
419 -- Natural earth data
420 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
422 RETURN nearcountry.country_code;
425 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
428 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
430 RETURN nearcountry.country_code;
433 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
435 -- Natural earth data
436 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
438 RETURN nearcountry.country_code;
444 LANGUAGE plpgsql IMMUTABLE;
446 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
451 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
453 RETURN lower(nearcountry.country_default_language_code);
458 LANGUAGE plpgsql IMMUTABLE;
460 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
465 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
467 RETURN lower(nearcountry.country_default_language_codes);
472 LANGUAGE plpgsql IMMUTABLE;
474 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
479 FOR nearcountry IN select partition from country_name where country_code = in_country_code
481 RETURN nearcountry.partition;
486 LANGUAGE plpgsql IMMUTABLE;
488 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
492 DELETE FROM location_area where place_id = OLD_place_id;
493 -- TODO:location_area
499 CREATE OR REPLACE FUNCTION add_location(
501 country_code varchar(2),
505 rank_address INTEGER,
520 IF rank_search > 25 THEN
521 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
524 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
526 x := deleteLocationArea(partition, place_id, rank_search);
529 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
532 centroid := ST_Centroid(geometry);
534 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
535 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
541 IF rank_address = 0 THEN
543 ELSEIF rank_search <= 14 THEN
545 ELSEIF rank_search <= 15 THEN
547 ELSEIF rank_search <= 16 THEN
549 ELSEIF rank_search <= 17 THEN
551 ELSEIF rank_search <= 21 THEN
553 ELSEIF rank_search = 25 THEN
557 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
559 secgeo := ST_Buffer(geometry, diameter);
560 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
571 -- find the parant road of an interpolation
572 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
573 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
578 parent_place_id BIGINT;
579 address_street_word_ids INTEGER[];
585 addr_street = street;
588 IF addr_street is null and addr_place is null THEN
589 select nodes from planet_osm_ways where id = wayid INTO waynodes;
590 FOR location IN SELECT placex.street, placex.addr_place from placex
591 where osm_type = 'N' and osm_id = ANY(waynodes)
592 and (placex.street is not null or placex.addr_place is not null)
593 and indexed_status < 100
595 addr_street = location.street;
596 addr_place = location.addr_place;
600 IF addr_street IS NOT NULL THEN
601 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
602 IF address_street_word_ids IS NOT NULL THEN
603 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
604 parent_place_id := location.place_id;
609 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
610 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
611 IF address_street_word_ids IS NOT NULL THEN
612 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
613 parent_place_id := location.place_id;
618 IF parent_place_id is null THEN
619 FOR location IN SELECT place_id FROM placex
620 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
621 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
622 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
623 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
625 parent_place_id := location.place_id;
629 IF parent_place_id is null THEN
633 RETURN parent_place_id;
638 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT,
639 parent_id BIGINT, partition INTEGER,
640 country_code TEXT, geometry_sector INTEGER,
641 defpostalcode TEXT, geom GEOMETRY) RETURNS INTEGER
653 orginalstartnumber INTEGER;
654 originalnumberrange INTEGER;
662 delete from placex where osm_type = 'W' and osm_id = wayid
663 and class = 'place' and type = 'address';
665 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
667 ELSEIF interpolationtype = 'all' THEN
669 ELSEIF interpolationtype ~ '^\d+$' THEN
670 stepsize := interpolationtype::INTEGER;
675 select nodes from planet_osm_ways where id = wayid INTO waynodes;
677 IF array_upper(waynodes, 1) IS NULL THEN
685 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
687 -- If there is a place of a type other than place/house, use that because
688 -- it is guaranteed to be the original node. For place/house types use the
689 -- one with the smallest id because the original node was created first.
690 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
691 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
692 and indexed_status < 100 and housenumber is not NULL
693 order by (type = 'address'),place_id limit 1 INTO nextnode;
694 IF nextnode.place_id IS NOT NULL THEN
696 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
697 -- Make sure that the point is actually on the line. That might
698 -- be a bit paranoid but ensures that the algorithm still works
699 -- should osm2pgsql attempt to repair geometries.
700 splitline := split_line_on_node(linegeo, nextnode.geometry);
701 sectiongeo := ST_GeometryN(splitline, 1);
702 linegeo := ST_GeometryN(splitline, 2);
704 sectiongeo = linegeo;
706 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
708 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
709 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
710 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
712 IF (startnumber > endnumber) THEN
713 housenum := endnumber;
714 endnumber := startnumber;
715 startnumber := housenum;
716 sectiongeo := ST_Reverse(sectiongeo);
718 orginalstartnumber := startnumber;
719 originalnumberrange := endnumber - startnumber;
721 startnumber := startnumber + stepsize;
722 -- correct for odd/even
723 IF (interpolationtype = 'odd' AND startnumber%2 = 0)
724 OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
725 startnumber := startnumber - 1;
727 endnumber := endnumber - 1;
729 -- keep for compatibility with previous versions
730 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id
731 and place_id != prevnode.place_id and class = 'place'
733 FOR housenum IN startnumber..endnumber BY stepsize LOOP
734 pointgeo := ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float);
735 insert into placex (place_id, partition, osm_type, osm_id,
736 class, type, admin_level, housenumber,
738 country_code, parent_place_id, rank_address, rank_search,
739 indexed_status, indexed_date, geometry_sector,
740 calculated_country_code, centroid, geometry)
741 values (nextval('seq_place'), partition, 'W', wayid,
742 'place', 'address', prevnode.admin_level, housenum,
743 coalesce(prevnode.postcode, defpostalcode),
744 prevnode.country_code, parent_id, 30, 30,
745 0, now(), geometry_sector, country_code,
747 newpoints := newpoints + 1;
748 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
752 -- early break if we are out of line string,
753 -- might happen when a line string loops back on itself
754 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
758 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
759 prevnode := nextnode;
763 --RAISE WARNING 'interpolation points % ',newpoints;
770 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
776 country_code VARCHAR(2);
777 default_language VARCHAR(10);
781 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
783 -- ignore interpolated addresses
784 IF NEW.class = 'place' and NEW.type = 'address' THEN
788 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
789 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
790 RAISE WARNING 'invalid geometry %',NEW.osm_id;
794 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
796 NEW.place_id := nextval('seq_place');
797 NEW.indexed_status := 1; --STATUS_NEW
799 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
801 NEW.partition := get_partition(NEW.calculated_country_code);
802 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
804 -- copy 'name' to or from the default language (if there is a default language)
805 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
806 default_language := get_country_language_code(NEW.calculated_country_code);
807 IF default_language IS NOT NULL THEN
808 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
809 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
810 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
811 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
816 IF NEW.admin_level > 15 THEN
817 NEW.admin_level := 15;
820 IF NEW.housenumber IS NOT NULL THEN
821 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
824 IF NEW.osm_type = 'X' THEN
825 -- E'X'ternal records should already be in the right format so do nothing
827 NEW.rank_search := 30;
828 NEW.rank_address := NEW.rank_search;
830 -- By doing in postgres we have the country available to us - currently only used for postcode
831 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
833 IF NEW.postcode IS NULL THEN
834 -- most likely just a part of a multipolygon postcode boundary, throw it away
838 NEW.name := hstore('ref', NEW.postcode);
840 IF NEW.calculated_country_code = 'gb' THEN
842 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
843 NEW.rank_search := 25;
844 NEW.rank_address := 5;
845 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
846 NEW.rank_search := 23;
847 NEW.rank_address := 5;
848 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
849 NEW.rank_search := 21;
850 NEW.rank_address := 5;
853 ELSEIF NEW.calculated_country_code = 'sg' THEN
855 IF NEW.postcode ~ '^([0-9]{6})$' THEN
856 NEW.rank_search := 25;
857 NEW.rank_address := 11;
860 ELSEIF NEW.calculated_country_code = 'de' THEN
862 IF NEW.postcode ~ '^([0-9]{5})$' THEN
863 NEW.rank_search := 21;
864 NEW.rank_address := 11;
868 -- Guess at the postcode format and coverage (!)
869 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
870 NEW.rank_search := 21;
871 NEW.rank_address := 11;
873 -- Does it look splitable into and area and local code?
874 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
876 IF postcode IS NOT NULL THEN
877 NEW.rank_search := 25;
878 NEW.rank_address := 11;
879 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
880 NEW.rank_search := 21;
881 NEW.rank_address := 11;
886 ELSEIF NEW.class = 'place' THEN
887 IF NEW.type in ('continent') THEN
888 NEW.rank_search := 2;
889 NEW.rank_address := NEW.rank_search;
890 NEW.calculated_country_code := NULL;
891 ELSEIF NEW.type in ('sea') THEN
892 NEW.rank_search := 2;
893 NEW.rank_address := 0;
894 NEW.calculated_country_code := NULL;
895 ELSEIF NEW.type in ('country') THEN
896 NEW.rank_search := 4;
897 NEW.rank_address := NEW.rank_search;
898 ELSEIF NEW.type in ('state') THEN
899 NEW.rank_search := 8;
900 NEW.rank_address := NEW.rank_search;
901 ELSEIF NEW.type in ('region') THEN
902 NEW.rank_search := 18; -- dropped from previous value of 10
903 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
904 ELSEIF NEW.type in ('county') THEN
905 NEW.rank_search := 12;
906 NEW.rank_address := NEW.rank_search;
907 ELSEIF NEW.type in ('city') THEN
908 NEW.rank_search := 16;
909 NEW.rank_address := NEW.rank_search;
910 ELSEIF NEW.type in ('island') THEN
911 NEW.rank_search := 17;
912 NEW.rank_address := 0;
913 ELSEIF NEW.type in ('town') THEN
914 NEW.rank_search := 18;
915 NEW.rank_address := 16;
916 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
917 NEW.rank_search := 19;
918 NEW.rank_address := 16;
919 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
920 NEW.rank_search := 20;
921 NEW.rank_address := NEW.rank_search;
922 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
923 NEW.rank_search := 20;
924 NEW.rank_address := 0;
925 -- Irish townlands, tagged as place=locality and locality=townland
926 IF (NEW.extratags -> 'locality') = 'townland' THEN
927 NEW.rank_address := 20;
929 ELSEIF NEW.type in ('neighbourhood') THEN
930 NEW.rank_search := 22;
931 NEW.rank_address := 22;
932 ELSEIF NEW.type in ('house','building') THEN
933 NEW.rank_search := 30;
934 NEW.rank_address := NEW.rank_search;
935 ELSEIF NEW.type in ('houses') THEN
936 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
937 NEW.rank_search := 28;
938 NEW.rank_address := 0;
941 ELSEIF NEW.class = 'boundary' THEN
942 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
943 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
946 NEW.rank_search := NEW.admin_level * 2;
947 IF NEW.type = 'administrative' THEN
948 NEW.rank_address := NEW.rank_search;
950 NEW.rank_address := 0;
952 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
953 NEW.rank_search := 22;
954 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
955 NEW.rank_address := NEW.rank_search;
957 NEW.rank_address := 0;
959 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
960 NEW.rank_search := 18;
961 NEW.rank_address := 0;
962 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
963 NEW.rank_search := 4;
964 NEW.rank_address := NEW.rank_search;
965 -- any feature more than 5 square miles is probably worth indexing
966 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
967 NEW.rank_search := 22;
968 NEW.rank_address := 0;
969 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
971 ELSEIF NEW.class = 'waterway' THEN
972 IF NEW.osm_type = 'R' THEN
973 NEW.rank_search := 16;
975 NEW.rank_search := 17;
977 NEW.rank_address := 0;
978 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
979 NEW.rank_search := 27;
980 NEW.rank_address := NEW.rank_search;
981 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
982 NEW.rank_search := 26;
983 NEW.rank_address := NEW.rank_search;
984 ELSEIF NEW.class = 'mountain_pass' THEN
985 NEW.rank_search := 20;
986 NEW.rank_address := 0;
991 IF NEW.rank_search > 30 THEN
992 NEW.rank_search := 30;
995 IF NEW.rank_address > 30 THEN
996 NEW.rank_address := 30;
999 IF (NEW.extratags -> 'capital') = 'yes' THEN
1000 NEW.rank_search := NEW.rank_search - 1;
1003 -- a country code make no sense below rank 4 (country)
1004 IF NEW.rank_search < 4 THEN
1005 NEW.calculated_country_code := NULL;
1008 -- Block import below rank 22
1009 -- IF NEW.rank_search > 22 THEN
1013 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1015 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1017 IF NEW.rank_address > 0 THEN
1018 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1019 -- Performance: We just can't handle re-indexing for country level changes
1020 IF st_area(NEW.geometry) < 1 THEN
1021 -- mark items within the geometry for re-indexing
1022 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1024 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1025 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1026 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));
1027 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1028 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));
1031 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1033 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1034 IF NEW.type='postcode' THEN
1036 ELSEIF NEW.rank_search < 16 THEN
1038 ELSEIF NEW.rank_search < 18 THEN
1040 ELSEIF NEW.rank_search < 20 THEN
1042 ELSEIF NEW.rank_search = 21 THEN
1044 ELSEIF NEW.rank_search < 24 THEN
1046 ELSEIF NEW.rank_search < 26 THEN
1047 diameter := 0.002; -- 100 to 200 meters
1048 ELSEIF NEW.rank_search < 28 THEN
1049 diameter := 0.001; -- 50 to 100 meters
1051 IF diameter > 0 THEN
1052 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1053 IF NEW.rank_search >= 26 THEN
1054 -- roads may cause reparenting for >27 rank places
1055 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1056 ELSEIF NEW.rank_search >= 16 THEN
1057 -- up to rank 16, street-less addresses may need reparenting
1058 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);
1060 -- for all other places the search terms may change as well
1061 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);
1068 -- add to tables for special search
1069 -- Note: won't work on initial import because the classtype tables
1070 -- do not yet exist. It won't hurt either.
1071 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1072 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1074 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1075 USING NEW.place_id, ST_Centroid(NEW.geometry);
1084 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1089 place_centroid GEOMETRY;
1091 search_maxdistance FLOAT[];
1092 search_mindistance FLOAT[];
1093 address_havelevel BOOLEAN[];
1100 relation_members TEXT[];
1102 linkedplacex RECORD;
1103 search_diameter FLOAT;
1104 search_prevdiameter FLOAT;
1105 search_maxrank INTEGER;
1106 address_maxrank INTEGER;
1107 address_street_word_id INTEGER;
1108 address_street_word_ids INTEGER[];
1109 parent_place_id_rank BIGINT;
1114 location_rank_search INTEGER;
1115 location_distance FLOAT;
1116 location_parent GEOMETRY;
1117 location_isaddress BOOLEAN;
1118 location_keywords INTEGER[];
1120 default_language TEXT;
1121 name_vector INTEGER[];
1122 nameaddress_vector INTEGER[];
1124 linked_node_id BIGINT;
1130 IF OLD.indexed_status = 100 THEN
1131 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1132 delete from placex where place_id = OLD.place_id;
1136 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1140 -- ignore interpolated addresses
1141 IF NEW.class = 'place' and NEW.type = 'address' THEN
1145 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1147 --RAISE WARNING '%',NEW.place_id;
1148 --RAISE WARNING '%', NEW;
1150 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1151 -- Silently do nothing
1155 -- TODO: this test is now redundant?
1156 IF OLD.indexed_status != 0 THEN
1158 NEW.indexed_date = now();
1160 result := deleteSearchName(NEW.partition, NEW.place_id);
1161 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1162 result := deleteRoad(NEW.partition, NEW.place_id);
1163 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1164 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1166 IF NEW.linked_place_id is not null THEN
1170 -- Speed up searches - just use the centroid of the feature
1171 -- cheaper but less acurate
1172 place_centroid := ST_PointOnSurface(NEW.geometry);
1173 NEW.centroid := null;
1175 -- recalculate country and partition
1176 IF NEW.rank_search = 4 THEN
1177 -- for countries, believe the mapped country code,
1178 -- so that we remain in the right partition if the boundaries
1180 NEW.partition := get_partition(lower(NEW.country_code));
1181 IF NEW.partition = 0 THEN
1182 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1183 NEW.partition := get_partition(NEW.calculated_country_code);
1185 NEW.calculated_country_code := lower(NEW.country_code);
1188 IF NEW.rank_search > 4 THEN
1189 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1190 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1192 NEW.calculated_country_code := NULL;
1194 NEW.partition := get_partition(NEW.calculated_country_code);
1196 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1199 IF NEW.class = 'place' AND NEW.type = 'houses'THEN
1200 IF NEW.osm_type = 'W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1201 NEW.parent_place_id := get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1202 NEW.partition, place_centroid, NEW.geometry);
1203 i := create_interpolation(NEW.osm_id, NEW.housenumber, NEW.parent_place_id,
1204 NEW.partition, NEW.calculated_country_code,
1205 NEW.geometry_sector, NEW.postcode, NEW.geometry);
1210 -- waterway ways are linked when they are part of a relation and have the same class/type
1211 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1212 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1214 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1215 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1216 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1217 FOR linked_node_id IN SELECT place_id FROM placex
1218 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1219 and class = NEW.class and type = NEW.type
1220 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1222 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1229 -- Adding ourselves to the list simplifies address calculations later
1230 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1232 -- What level are we searching from
1233 search_maxrank := NEW.rank_search;
1235 -- Thought this wasn't needed but when we add new languages to the country_name table
1236 -- we need to update the existing names
1237 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1238 default_language := get_country_language_code(NEW.calculated_country_code);
1239 IF default_language IS NOT NULL THEN
1240 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1241 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1242 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1243 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1248 -- Initialise the name vector using our name
1249 name_vector := make_keywords(NEW.name);
1250 nameaddress_vector := '{}'::int[];
1253 address_havelevel[i] := false;
1256 NEW.importance := null;
1257 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1258 IF NEW.importance IS NULL THEN
1259 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;
1262 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1264 -- For low level elements we inherit from our parent road
1265 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1267 --RAISE WARNING 'finding street for %', NEW;
1269 -- We won't get a better centroid, besides these places are too small to care
1270 NEW.centroid := place_centroid;
1272 NEW.parent_place_id := null;
1274 -- if we have a POI and there is no address information,
1275 -- see if we can get it from a surrounding building
1276 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1277 AND NEW.housenumber IS NULL THEN
1278 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1279 and (housenumber is not null or street is not null or addr_place is not null)
1280 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1283 NEW.housenumber := location.housenumber;
1284 NEW.street := location.street;
1285 NEW.addr_place := location.addr_place;
1289 -- We have to find our parent road.
1290 -- Copy data from linked items (points on ways, addr:street links, relations)
1292 -- Is this object part of a relation?
1293 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1295 -- At the moment we only process one type of relation - associatedStreet
1296 IF relation.tags @> ARRAY['associatedStreet'] THEN
1297 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1298 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1299 --RAISE WARNING 'node in relation %',relation;
1300 SELECT place_id from placex where osm_type = 'W'
1301 and osm_id = substring(relation.members[i],2,200)::bigint
1302 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1309 -- Note that addr:street links can only be indexed once the street itself is indexed
1310 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1311 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1312 IF address_street_word_ids IS NOT NULL THEN
1313 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1314 NEW.parent_place_id := location.place_id;
1319 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1320 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1321 IF address_street_word_ids IS NOT NULL THEN
1322 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1323 NEW.parent_place_id := location.place_id;
1328 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1330 --RAISE WARNING 'x1';
1331 -- Is this node part of a way?
1332 FOR location IN select p.* from placex p, planet_osm_ways w
1333 where p.osm_type = 'W' and p.rank_search >= 26
1334 and p.geometry && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes)
1336 --RAISE WARNING '%', location;
1337 -- Way IS a road then we are on it - that must be our road
1338 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1339 --RAISE WARNING 'node in way that is a street %',location;
1340 NEW.parent_place_id := location.place_id;
1343 -- If this way is a street interpolation line then it is probably as good as we are going to get
1344 IF NEW.parent_place_id IS NULL AND location.class = 'place' and location.type='houses' THEN
1345 NEW.parent_place_id := location.parent_place_id;
1348 -- Is the WAY part of a relation
1349 IF NEW.parent_place_id IS NULL THEN
1350 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1352 -- At the moment we only process one type of relation - associatedStreet
1353 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1354 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1355 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1356 --RAISE WARNING 'node in way that is in a relation %',relation;
1357 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1358 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1365 -- If the way mentions a street or place address, try that for parenting.
1366 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1367 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1368 IF address_street_word_ids IS NOT NULL THEN
1369 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1370 NEW.parent_place_id := linkedplacex.place_id;
1375 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1376 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1377 IF address_street_word_ids IS NOT NULL THEN
1378 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1379 NEW.parent_place_id := linkedplacex.place_id;
1388 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1389 -- Still nothing, just use the nearest road
1390 IF NEW.parent_place_id IS NULL THEN
1391 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1392 NEW.parent_place_id := location.place_id;
1397 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1399 -- If we didn't find any road fallback to standard method
1400 IF NEW.parent_place_id IS NOT NULL THEN
1402 -- Get the details of the parent road
1403 select * from search_name where place_id = NEW.parent_place_id INTO location;
1404 NEW.calculated_country_code := location.country_code;
1406 -- Merge the postcode into the parent's address if necessary XXXX
1407 IF NEW.postcode IS NOT NULL THEN
1408 isin_tokens := '{}'::int[];
1409 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1410 IF address_street_word_id is not null
1411 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1412 isin_tokens := isin_tokens || address_street_word_id;
1414 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1415 IF address_street_word_id is not null
1416 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1417 isin_tokens := isin_tokens || address_street_word_id;
1419 IF isin_tokens != '{}'::int[] THEN
1421 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1422 WHERE place_id = NEW.parent_place_id;
1426 --RAISE WARNING '%', NEW.name;
1427 -- If there is no name it isn't searchable, don't bother to create a search record
1428 IF NEW.name is NULL THEN
1432 -- Merge address from parent
1433 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1434 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1436 -- Performance, it would be more acurate to do all the rest of the import
1437 -- process but it takes too long
1438 -- Just be happy with inheriting from parent road only
1440 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1441 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1444 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);
1451 -- RAISE WARNING ' INDEXING Started:';
1452 -- RAISE WARNING ' INDEXING: %',NEW;
1454 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1456 -- see if we have any special relation members
1457 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1459 -- RAISE WARNING 'get_osm_rel_members, label';
1460 IF relation_members IS NOT NULL THEN
1461 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1463 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1464 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1466 -- If we don't already have one use this as the centre point of the geometry
1467 IF NEW.centroid IS NULL THEN
1468 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1471 -- merge in the label name, re-init word vector
1472 IF NOT linkedPlacex.name IS NULL THEN
1473 NEW.name := linkedPlacex.name || NEW.name;
1474 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1477 -- merge in extra tags
1478 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1480 -- mark the linked place (excludes from search results)
1481 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1483 -- keep a note of the node id in case we need it for wikipedia in a bit
1484 linked_node_id := linkedPlacex.osm_id;
1489 IF NEW.centroid IS NULL THEN
1491 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1493 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1494 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1496 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1497 -- But that can be fixed by explicitly setting the label in the data
1498 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1499 AND NEW.rank_address = linkedPlacex.rank_address THEN
1501 -- If we don't already have one use this as the centre point of the geometry
1502 IF NEW.centroid IS NULL THEN
1503 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1506 -- merge in the name, re-init word vector
1507 IF NOT linkedPlacex.name IS NULL THEN
1508 NEW.name := linkedPlacex.name || NEW.name;
1509 name_vector := make_keywords(NEW.name);
1512 -- merge in extra tags
1513 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1515 -- mark the linked place (excludes from search results)
1516 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1518 -- keep a note of the node id in case we need it for wikipedia in a bit
1519 linked_node_id := linkedPlacex.osm_id;
1531 -- Name searches can be done for ways as well as relations
1532 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1534 -- not found one yet? how about doing a name search
1535 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1537 FOR linkedPlacex IN select placex.* from placex WHERE
1538 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1539 AND placex.rank_address = NEW.rank_address
1540 AND placex.place_id != NEW.place_id
1541 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1542 AND st_covers(NEW.geometry, placex.geometry)
1545 -- If we don't already have one use this as the centre point of the geometry
1546 IF NEW.centroid IS NULL THEN
1547 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1550 -- merge in the name, re-init word vector
1551 NEW.name := linkedPlacex.name || NEW.name;
1552 name_vector := make_keywords(NEW.name);
1554 -- merge in extra tags
1555 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1557 -- mark the linked place (excludes from search results)
1558 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1560 -- keep a note of the node id in case we need it for wikipedia in a bit
1561 linked_node_id := linkedPlacex.osm_id;
1565 IF NEW.centroid IS NOT NULL THEN
1566 place_centroid := NEW.centroid;
1567 -- Place might have had only a name tag before but has now received translations
1568 -- from the linked place. Make sure a name tag for the default language exists in
1570 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1571 default_language := get_country_language_code(NEW.calculated_country_code);
1572 IF default_language IS NOT NULL THEN
1573 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1574 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1575 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1576 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1582 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1583 IF NEW.importance is null THEN
1584 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1586 -- Still null? how about looking it up by the node id
1587 IF NEW.importance IS NULL THEN
1588 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;
1593 -- make sure all names are in the word table
1594 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1595 perform create_country(NEW.name, lower(NEW.country_code));
1598 NEW.parent_place_id = 0;
1599 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 -- for the USA we have an additional address table. Merge in zip codes from there too
1641 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1642 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1643 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1644 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1645 isin_tokens := isin_tokens || address_street_word_id;
1647 -- also merge in the single word version
1648 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1649 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1653 -- RAISE WARNING 'ISIN: %', isin_tokens;
1655 -- Process area matches
1656 location_rank_search := 0;
1657 location_distance := 0;
1658 location_parent := NULL;
1659 -- added ourself as address already
1660 address_havelevel[NEW.rank_address] := true;
1661 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1662 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1664 --RAISE WARNING ' AREA: %',location;
1666 IF location.rank_address != location_rank_search THEN
1667 location_rank_search := location.rank_address;
1668 IF location.isguess THEN
1669 location_distance := location.distance * 1.5;
1671 IF location.rank_address <= 12 THEN
1672 -- for county and above, if we have an area consider that exact
1673 -- (It would be nice to relax the constraint for places close to
1674 -- the boundary but we'd need the exact geometry for that. Too
1676 location_distance = 0;
1678 -- Below county level remain slightly fuzzy.
1679 location_distance := location.distance * 0.5;
1683 CONTINUE WHEN location.keywords <@ location_keywords;
1686 IF location.distance < location_distance OR NOT location.isguess THEN
1687 location_keywords := location.keywords;
1689 location_isaddress := NOT address_havelevel[location.rank_address];
1690 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1691 location_isaddress := ST_Contains(location_parent,location.centroid);
1694 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1695 -- Add it to the list of search terms
1696 IF location.rank_search > 4 THEN
1697 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1699 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1701 IF location_isaddress THEN
1703 address_havelevel[location.rank_address] := true;
1704 IF NOT location.isguess THEN
1705 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1708 IF location.rank_address > parent_place_id_rank THEN
1709 NEW.parent_place_id = location.place_id;
1710 parent_place_id_rank = location.rank_address;
1715 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1721 -- try using the isin value to find parent places
1722 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1723 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1724 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1725 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1727 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1729 --RAISE WARNING ' ISIN: %',location;
1731 IF location.rank_search > 4 THEN
1732 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1733 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1734 address_havelevel[location.rank_address] := true;
1736 IF location.rank_address > parent_place_id_rank THEN
1737 NEW.parent_place_id = location.place_id;
1738 parent_place_id_rank = location.rank_address;
1748 -- for long ways we should add search terms for the entire length
1749 IF st_length(NEW.geometry) > 0.05 THEN
1751 location_rank_search := 0;
1752 location_distance := 0;
1754 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1756 IF location.rank_address != location_rank_search THEN
1757 location_rank_search := location.rank_address;
1758 location_distance := location.distance * 1.5;
1761 IF location.rank_search > 4 AND location.distance < location_distance THEN
1763 -- Add it to the list of search terms
1764 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1765 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1773 -- if we have a name add this to the name search table
1774 IF NEW.name IS NOT NULL THEN
1776 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1777 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1780 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1781 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1784 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);
1788 -- If we've not managed to pick up a better one - default centroid
1789 IF NEW.centroid IS NULL THEN
1790 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;
1832 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1834 IF OLD.rank_address < 26 THEN
1835 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1838 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1840 IF OLD.name is not null THEN
1841 b := deleteSearchName(OLD.partition, OLD.place_id);
1844 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1846 DELETE FROM place_addressline where place_id = OLD.place_id;
1848 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1850 -- remove from tables for special search
1851 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1852 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1854 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1857 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1865 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1871 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1873 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1874 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1875 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;
1877 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1883 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;
1885 -- interpolations are special
1886 IF OLD.class = 'place' and OLD.type = 'houses' THEN
1887 UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = 'place' and type = 'address';
1896 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1901 existingplacex RECORD;
1902 existinggeometry GEOMETRY;
1903 existingplace_id BIGINT;
1908 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1909 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1911 IF FALSE and NEW.osm_type = 'R' THEN
1912 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;
1913 --DEBUG: RAISE WARNING '%', existingplacex;
1916 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
1917 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1918 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1919 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1923 -- Patch in additional country names
1924 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1925 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1928 -- Have we already done this place?
1929 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;
1931 -- Get the existing place_id
1932 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;
1934 -- Handle a place changing type by removing the old data
1935 -- My generated 'place' types are causing havok because they overlap with real keys
1936 -- TODO: move them to their own special purpose key/class to avoid collisions
1937 IF existing.osm_type IS NULL THEN
1938 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1941 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1942 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1945 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1946 AND st_area(existing.geometry) > 0.02
1947 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1948 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1950 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1951 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1955 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1956 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1958 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
1959 IF existingplacex.osm_type IS NULL OR
1960 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
1963 IF existingplacex.osm_type IS NOT NULL THEN
1964 -- sanity check: ignore admin_level changes on places with too many active children
1965 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
1966 --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;
1967 --LIMIT INDEXING: IF i > 100000 THEN
1968 --LIMIT INDEXING: RETURN null;
1969 --LIMIT INDEXING: END IF;
1972 IF existing.osm_type IS NOT NULL THEN
1973 -- pathological case caused by the triggerless copy into place during initial import
1974 -- force delete even for large areas, it will be reinserted later
1975 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;
1976 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1979 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1980 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1981 street, addr_place, isin, postcode, country_code, extratags, geometry)
1982 values (NEW.osm_type
1998 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2003 -- Various ways to do the update
2005 -- Debug, what's changed?
2007 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2008 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2010 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2011 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2013 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2014 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2016 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2017 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2019 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2020 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2022 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2023 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2025 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2026 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2030 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2031 IF existing.geometry::text != NEW.geometry::text
2032 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2033 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2036 -- Get the version of the geometry actually used (in placex table)
2037 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;
2039 -- Performance limit
2040 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2042 -- 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
2043 update placex set indexed_status = 2 where indexed_status = 0 and
2044 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2045 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2046 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2048 update placex set indexed_status = 2 where indexed_status = 0 and
2049 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2050 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2051 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2058 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2059 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2060 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2061 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2062 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2063 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2064 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2065 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2066 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2067 OR existing.geometry::text != NEW.geometry::text
2072 housenumber = NEW.housenumber,
2073 street = NEW.street,
2074 addr_place = NEW.addr_place,
2076 postcode = NEW.postcode,
2077 country_code = NEW.country_code,
2078 extratags = NEW.extratags,
2079 admin_level = NEW.admin_level,
2080 geometry = NEW.geometry
2081 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2083 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2084 IF NEW.postcode IS NULL THEN
2085 -- postcode was deleted, no longer retain in placex
2086 DELETE FROM placex where place_id = existingplacex.place_id;
2090 NEW.name := hstore('ref', NEW.postcode);
2095 housenumber = NEW.housenumber,
2096 street = NEW.street,
2097 addr_place = NEW.addr_place,
2099 postcode = NEW.postcode,
2100 country_code = NEW.country_code,
2101 parent_place_id = null,
2102 extratags = NEW.extratags,
2103 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2105 geometry = NEW.geometry
2106 where place_id = existingplacex.place_id;
2110 -- for interpolations invalidate all nodes on the line
2111 IF NEW.class = 'place' and NEW.type = 'houses' and NEW.osm_type = 'W' THEN
2112 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);
2115 -- Abort the add (we modified the existing place instead)
2119 $$ LANGUAGE plpgsql;
2121 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2128 IF name is null THEN
2132 search := languagepref;
2134 FOR j IN 1..array_upper(search, 1) LOOP
2135 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2136 return trim(name->search[j]);
2140 -- anything will do as a fallback - just take the first name type thing there is
2141 search := avals(name);
2145 LANGUAGE plpgsql IMMUTABLE;
2148 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2159 search := ARRAY['ref'];
2162 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2165 select rank_address,name,distance,length(name::text) as namelength
2166 from place_addressline join placex on (address_place_id = placex.place_id)
2167 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2168 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2170 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2171 FOR j IN 1..array_upper(search, 1) LOOP
2172 FOR k IN 1..array_upper(location.name, 1) LOOP
2173 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
2174 result[(100 - location.rank_address)] := trim(location.name[k].value);
2175 found := location.rank_address;
2182 RETURN array_to_string(result,', ');
2187 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2199 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2200 currresult := trim(get_name_by_language(location.name, languagepref));
2201 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2202 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2203 prevresult := currresult;
2207 RETURN array_to_string(result,', ');
2212 DROP TYPE IF EXISTS addressline CASCADE;
2213 create type addressline as (
2220 admin_level INTEGER,
2223 rank_address INTEGER,
2227 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2230 for_place_id BIGINT;
2235 countrylocation RECORD;
2236 searchcountrycode varchar(2);
2237 searchhousenumber TEXT;
2238 searchhousename HSTORE;
2239 searchrankaddress INTEGER;
2240 searchpostcode TEXT;
2247 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2248 WHERE place_id = in_place_id
2249 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2251 IF for_place_id IS NULL THEN
2252 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2253 WHERE place_id = in_place_id
2254 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2257 IF for_place_id IS NULL THEN
2258 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2259 WHERE place_id = in_place_id and rank_address = 30
2260 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2263 IF for_place_id IS NULL THEN
2264 select coalesce(linked_place_id, place_id), calculated_country_code,
2265 housenumber, rank_search, postcode, null
2266 from placex where place_id = in_place_id
2267 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2270 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2273 hadcountry := false;
2275 select placex.place_id, osm_type, osm_id,
2276 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2277 class, type, admin_level, true as fromarea, true as isaddress,
2278 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2279 0 as distance, calculated_country_code, postcode
2281 where place_id = for_place_id
2283 --RAISE WARNING '%',location;
2284 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2285 searchcountrycode := location.calculated_country_code;
2287 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2288 location.isaddress := FALSE;
2290 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2291 searchpostcode := location.postcode;
2293 IF location.rank_address = 4 AND location.isaddress THEN
2296 IF location.rank_address < 4 AND NOT hadcountry THEN
2297 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2298 IF countryname IS NOT NULL THEN
2299 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2300 RETURN NEXT countrylocation;
2303 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2304 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2305 location.distance)::addressline;
2306 RETURN NEXT countrylocation;
2307 found := location.rank_address;
2311 select placex.place_id, osm_type, osm_id,
2312 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2313 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2314 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2315 admin_level, fromarea, isaddress,
2316 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,
2317 distance,calculated_country_code,postcode
2318 from place_addressline join placex on (address_place_id = placex.place_id)
2319 where place_addressline.place_id = for_place_id
2320 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2321 and address_place_id != for_place_id
2322 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2323 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2325 --RAISE WARNING '%',location;
2326 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2327 searchcountrycode := location.calculated_country_code;
2329 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2330 location.isaddress := FALSE;
2332 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2333 searchpostcode := location.postcode;
2335 IF location.rank_address = 4 AND location.isaddress THEN
2338 IF location.rank_address < 4 AND NOT hadcountry THEN
2339 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2340 IF countryname IS NOT NULL THEN
2341 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2342 RETURN NEXT countrylocation;
2345 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2346 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2347 location.distance)::addressline;
2348 RETURN NEXT countrylocation;
2349 found := location.rank_address;
2353 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2354 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2355 IF countryname IS NOT NULL THEN
2356 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2357 RETURN NEXT location;
2361 IF searchcountrycode IS NOT NULL THEN
2362 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2363 RETURN NEXT location;
2366 IF searchhousename IS NOT NULL THEN
2367 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2368 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2369 RETURN NEXT location;
2372 IF searchhousenumber IS NOT NULL THEN
2373 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2374 RETURN NEXT location;
2377 IF searchpostcode IS NOT NULL THEN
2378 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2379 RETURN NEXT location;
2388 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2391 numfeatures integer;
2395 housenumber = place.housenumber,
2396 street = place.street,
2397 addr_place = place.addr_place,
2399 postcode = place.postcode,
2400 country_code = place.country_code,
2401 parent_place_id = null
2403 where placex.place_id = search_place_id
2404 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2405 and place.class = placex.class and place.type = placex.type;
2406 update placex set indexed_status = 2 where place_id = search_place_id;
2407 update placex set indexed_status = 0 where place_id = search_place_id;
2413 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2419 ELSEIF rank < 4 THEN
2421 ELSEIF rank < 8 THEN
2423 ELSEIF rank < 12 THEN
2425 ELSEIF rank < 16 THEN
2427 ELSEIF rank = 16 THEN
2429 ELSEIF rank = 17 THEN
2430 RETURN 'Town / Island';
2431 ELSEIF rank = 18 THEN
2432 RETURN 'Village / Hamlet';
2433 ELSEIF rank = 20 THEN
2435 ELSEIF rank = 21 THEN
2436 RETURN 'Postcode Area';
2437 ELSEIF rank = 22 THEN
2438 RETURN 'Croft / Farm / Locality / Islet';
2439 ELSEIF rank = 23 THEN
2440 RETURN 'Postcode Area';
2441 ELSEIF rank = 25 THEN
2442 RETURN 'Postcode Point';
2443 ELSEIF rank = 26 THEN
2444 RETURN 'Street / Major Landmark';
2445 ELSEIF rank = 27 THEN
2446 RETURN 'Minory Street / Path';
2447 ELSEIF rank = 28 THEN
2448 RETURN 'House / Building';
2450 RETURN 'Other: '||rank;
2457 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2463 ELSEIF rank < 2 THEN
2465 ELSEIF rank < 4 THEN
2467 ELSEIF rank = 5 THEN
2469 ELSEIF rank < 8 THEN
2471 ELSEIF rank < 12 THEN
2473 ELSEIF rank < 16 THEN
2475 ELSEIF rank = 16 THEN
2477 ELSEIF rank = 17 THEN
2478 RETURN 'Town / Village / Hamlet';
2479 ELSEIF rank = 20 THEN
2481 ELSEIF rank = 21 THEN
2482 RETURN 'Postcode Area';
2483 ELSEIF rank = 22 THEN
2484 RETURN 'Croft / Farm / Locality / Islet';
2485 ELSEIF rank = 23 THEN
2486 RETURN 'Postcode Area';
2487 ELSEIF rank = 25 THEN
2488 RETURN 'Postcode Point';
2489 ELSEIF rank = 26 THEN
2490 RETURN 'Street / Major Landmark';
2491 ELSEIF rank = 27 THEN
2492 RETURN 'Minory Street / Path';
2493 ELSEIF rank = 28 THEN
2494 RETURN 'House / Building';
2496 RETURN 'Other: '||rank;
2503 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2504 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2509 place_centroid GEOMETRY;
2510 out_partition INTEGER;
2511 out_parent_place_id BIGINT;
2513 address_street_word_id INTEGER;
2518 place_centroid := ST_Centroid(pointgeo);
2519 out_partition := get_partition(in_countrycode);
2520 out_parent_place_id := null;
2522 address_street_word_id := get_name_id(make_standard_name(in_street));
2523 IF address_street_word_id IS NOT NULL THEN
2524 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2525 out_parent_place_id := location.place_id;
2529 IF out_parent_place_id IS NULL THEN
2530 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2531 out_parent_place_id := location.place_id;
2535 out_postcode := in_postcode;
2536 IF out_postcode IS NULL THEN
2537 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2539 IF out_postcode IS NULL THEN
2540 out_postcode := getNearestPostcode(out_partition, place_centroid);
2544 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2545 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2546 newpoints := newpoints + 1;
2553 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2560 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2561 IF members[i+1] = member THEN
2562 result := result || members[i];
2571 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2577 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2578 IF members[i+1] = ANY(memberLabels) THEN
2579 RETURN NEXT members[i];
2588 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2589 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2591 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2592 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
2593 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2594 ), '') AS bytea), 'UTF8');
2596 LANGUAGE SQL IMMUTABLE STRICT;
2598 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2602 RETURN decode_url_part(p);
2604 WHEN others THEN return null;
2607 LANGUAGE plpgsql IMMUTABLE;
2609 DROP TYPE wikipedia_article_match CASCADE;
2610 create type wikipedia_article_match as (
2616 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2622 wiki_article_title TEXT;
2623 wiki_article_language TEXT;
2624 result wikipedia_article_match;
2626 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'];
2628 WHILE langs[i] IS NOT NULL LOOP
2629 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2630 IF wiki_article is not null THEN
2631 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2632 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2633 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2634 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2635 wiki_article := replace(wiki_article,' ','_');
2636 IF strpos(wiki_article, ':') IN (3,4) THEN
2637 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2638 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2640 wiki_article_title := trim(wiki_article);
2641 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;
2644 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2645 from wikipedia_article
2646 where language = wiki_article_language and
2647 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2649 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2650 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2651 where wikipedia_redirect.language = wiki_article_language and
2652 (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'\\',''))
2653 order by importance desc limit 1 INTO result;
2655 IF result.language is not null THEN
2666 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2667 RETURNS SETOF GEOMETRY
2681 remainingdepth INTEGER;
2686 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2688 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2689 RETURN NEXT geometry;
2693 remainingdepth := maxdepth - 1;
2694 area := ST_AREA(geometry);
2695 IF remainingdepth < 1 OR area < maxarea THEN
2696 RETURN NEXT geometry;
2700 xmin := st_xmin(geometry);
2701 xmax := st_xmax(geometry);
2702 ymin := st_ymin(geometry);
2703 ymax := st_ymax(geometry);
2704 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2706 -- if the geometry completely covers the box don't bother to slice any more
2707 IF ST_AREA(secbox) = area THEN
2708 RETURN NEXT geometry;
2712 xmid := (xmin+xmax)/2;
2713 ymid := (ymin+ymax)/2;
2716 FOR seg IN 1..4 LOOP
2719 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2722 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2725 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2728 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2731 IF st_intersects(geometry, secbox) THEN
2732 secgeo := st_intersection(geometry, secbox);
2733 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2734 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2735 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2737 RETURN NEXT geo.geom;
2749 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2750 RETURNS SETOF GEOMETRY
2755 -- 10000000000 is ~~ 1x1 degree
2756 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2757 RETURN NEXT geo.geom;
2765 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2769 osmtype character(1);
2773 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2774 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2775 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2776 -- force delete from place/placex by making it a very small geometry
2777 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;
2778 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2785 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2793 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2794 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2795 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2796 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2797 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2798 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2799 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));
2800 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2801 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));
2807 ELSEIF rank < 18 THEN
2809 ELSEIF rank < 20 THEN
2811 ELSEIF rank = 21 THEN
2813 ELSEIF rank < 24 THEN
2815 ELSEIF rank < 26 THEN
2816 diameter := 0.002; -- 100 to 200 meters
2817 ELSEIF rank < 28 THEN
2818 diameter := 0.001; -- 50 to 100 meters
2820 IF diameter > 0 THEN
2822 -- roads may cause reparenting for >27 rank places
2823 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2824 ELSEIF rank >= 16 THEN
2825 -- up to rank 16, street-less addresses may need reparenting
2826 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);
2828 -- for all other places the search terms may change as well
2829 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);