1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
55 NEWgeometry := ST_PointOnSurface(place);
56 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
57 -- NEWgeometry := ST_buffer(NEWgeometry,0);
58 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
62 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
68 AS '{modulepath}/nominatim.so', 'transliteration'
69 LANGUAGE c IMMUTABLE STRICT;
71 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
72 AS '{modulepath}/nominatim.so', 'gettokenstring'
73 LANGUAGE c IMMUTABLE STRICT;
75 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
80 o := gettokenstring(transliteration(name));
81 RETURN trim(substr(o,1,length(o)));
84 LANGUAGE 'plpgsql' IMMUTABLE;
86 -- returns NULL if the word is too common
87 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
92 return_word_id INTEGER;
95 lookup_token := trim(lookup_word);
96 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;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
101 IF count > get_maxwordfreq() THEN
102 return_word_id := NULL;
105 RETURN return_word_id;
110 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word 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='place' and type='house' 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, null, 'place', 'house', null, 0, null);
123 RETURN return_word_id;
128 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
133 return_word_id INTEGER;
135 lookup_token := ' '||trim(lookup_word);
136 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
137 IF return_word_id IS NULL THEN
138 return_word_id := nextval('seq_word');
139 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
141 RETURN return_word_id;
146 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
151 return_word_id INTEGER;
153 lookup_token := ' '||trim(lookup_word);
154 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
155 IF return_word_id IS NULL THEN
156 return_word_id := nextval('seq_word');
157 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
159 RETURN return_word_id;
164 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
169 return_word_id INTEGER;
171 lookup_token := lookup_class||'='||lookup_type;
172 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
173 IF return_word_id IS NULL THEN
174 return_word_id := nextval('seq_word');
175 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
177 RETURN return_word_id;
182 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
187 return_word_id INTEGER;
189 lookup_token := lookup_class||'='||lookup_type;
190 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
191 RETURN return_word_id;
196 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
201 return_word_id INTEGER;
203 lookup_token := ' '||trim(lookup_word);
204 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;
205 IF return_word_id IS NULL THEN
206 return_word_id := nextval('seq_word');
207 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
209 RETURN return_word_id;
214 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
219 nospace_lookup_token TEXT;
220 return_word_id INTEGER;
222 lookup_token := ' '||trim(lookup_word);
223 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
224 IF return_word_id IS NULL THEN
225 return_word_id := nextval('seq_word');
226 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
227 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
228 -- IF ' '||nospace_lookup_token != lookup_token THEN
229 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
232 RETURN return_word_id;
237 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
242 RETURN getorcreate_name_id(lookup_word, '');
247 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
252 return_word_id INTEGER;
254 lookup_token := trim(lookup_word);
255 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
256 RETURN return_word_id;
259 LANGUAGE plpgsql IMMUTABLE;
261 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
266 return_word_id INTEGER;
268 lookup_token := ' '||trim(lookup_word);
269 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
270 RETURN return_word_id;
273 LANGUAGE plpgsql IMMUTABLE;
275 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
282 IF array_upper(a, 1) IS NULL THEN
285 IF array_upper(b, 1) IS NULL THEN
289 FOR i IN 1..array_upper(b, 1) LOOP
290 IF NOT (ARRAY[b[i]] <@ r) THEN
297 LANGUAGE plpgsql IMMUTABLE;
299 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
308 FOR item IN SELECT (each(src)).* LOOP
310 s := make_standard_name(item.value);
311 w := getorcreate_country(s, lookup_country_code);
313 words := regexp_split_to_array(item.value, E'[,;()]');
314 IF array_upper(words, 1) != 1 THEN
315 FOR j IN 1..array_upper(words, 1) LOOP
316 s := make_standard_name(words[j]);
318 w := getorcreate_country(s, lookup_country_code);
327 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
337 result := '{}'::INTEGER[];
339 FOR item IN SELECT (each(src)).* LOOP
341 s := make_standard_name(item.value);
343 w := getorcreate_name_id(s, item.value);
345 IF not(ARRAY[w] <@ result) THEN
346 result := result || w;
349 words := string_to_array(s, ' ');
350 IF array_upper(words, 1) IS NOT NULL THEN
351 FOR j IN 1..array_upper(words, 1) LOOP
352 IF (words[j] != '') THEN
353 w = getorcreate_word_id(words[j]);
354 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
355 result := result || w;
361 words := regexp_split_to_array(item.value, E'[,;()]');
362 IF array_upper(words, 1) != 1 THEN
363 FOR j IN 1..array_upper(words, 1) LOOP
364 s := make_standard_name(words[j]);
366 w := getorcreate_word_id(s);
367 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
368 result := result || w;
374 s := regexp_replace(item.value, '市$', '');
375 IF s != item.value THEN
376 s := make_standard_name(s);
378 w := getorcreate_name_id(s, item.value);
379 IF NOT (ARRAY[w] <@ result) THEN
380 result := result || w;
390 LANGUAGE plpgsql IMMUTABLE;
392 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
402 result := '{}'::INTEGER[];
404 s := make_standard_name(src);
405 w := getorcreate_name_id(s, src);
407 IF NOT (ARRAY[w] <@ result) THEN
408 result := result || w;
411 words := string_to_array(s, ' ');
412 IF array_upper(words, 1) IS NOT NULL THEN
413 FOR j IN 1..array_upper(words, 1) LOOP
414 IF (words[j] != '') THEN
415 w = getorcreate_word_id(words[j]);
416 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
417 result := result || w;
423 words := regexp_split_to_array(src, E'[,;()]');
424 IF array_upper(words, 1) != 1 THEN
425 FOR j IN 1..array_upper(words, 1) LOOP
426 s := make_standard_name(words[j]);
428 w := getorcreate_word_id(s);
429 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
430 result := result || w;
436 s := regexp_replace(src, '市$', '');
438 s := make_standard_name(s);
440 w := getorcreate_name_id(s, src);
441 IF NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
450 LANGUAGE plpgsql IMMUTABLE;
452 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
459 IF (wordscores is null OR words is null) THEN
464 FOR idxword in 1 .. array_upper(words, 1) LOOP
465 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
466 IF wordscores[idxscores].word = words[idxword] THEN
467 result := result + wordscores[idxscores].score;
475 LANGUAGE plpgsql IMMUTABLE;
477 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
480 place_centre GEOMETRY;
483 place_centre := ST_PointOnSurface(place);
485 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
487 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
489 -- Try for OSM fallback data
490 -- The order is to deal with places like HongKong that are 'states' within another polygon
491 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
493 RETURN nearcountry.country_code;
496 -- Try for a OSM polygon
497 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
499 RETURN nearcountry.country_code;
502 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
504 -- Natural earth data
505 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
507 RETURN nearcountry.country_code;
510 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
513 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
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
520 -- Natural earth data
521 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
523 RETURN nearcountry.country_code;
526 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
527 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
529 -- RETURN nearcountry.country_code;
532 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
534 -- Still not in a country - try nearest within ~12 miles of a country
535 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
536 -- order by st_distance(geometry, place) limit 1
538 -- RETURN nearcountry.country_code;
544 LANGUAGE plpgsql IMMUTABLE;
546 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
551 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
553 RETURN nearcountry.country_code;
555 RETURN get_country_code(place);
558 LANGUAGE plpgsql IMMUTABLE;
560 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
565 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
567 RETURN lower(nearcountry.country_default_language_code);
572 LANGUAGE plpgsql IMMUTABLE;
574 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
579 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
581 RETURN lower(nearcountry.country_default_language_codes);
586 LANGUAGE plpgsql IMMUTABLE;
588 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
591 place_centre GEOMETRY;
594 FOR nearcountry IN select partition from country_name where country_code = in_country_code
596 RETURN nearcountry.partition;
601 LANGUAGE plpgsql IMMUTABLE;
603 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
607 DELETE FROM location_area where place_id = OLD_place_id;
608 -- TODO:location_area
614 CREATE OR REPLACE FUNCTION add_location(
616 country_code varchar(2),
620 rank_address INTEGER,
635 IF rank_search > 25 THEN
636 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
639 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
641 x := deleteLocationArea(partition, place_id);
644 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
647 centroid := ST_Centroid(geometry);
649 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
650 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
653 ELSEIF rank_search < 26 THEN
656 IF rank_address = 0 THEN
658 ELSEIF rank_search <= 14 THEN
660 ELSEIF rank_search <= 15 THEN
662 ELSEIF rank_search <= 16 THEN
664 ELSEIF rank_search <= 17 THEN
666 ELSEIF rank_search <= 21 THEN
668 ELSEIF rank_search = 25 THEN
672 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
674 secgeo := ST_Buffer(geometry, diameter);
675 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
680 secgeo := ST_Buffer(geometry, 0.0002);
681 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
684 secgeo := ST_Buffer(geometry, 0.001);
685 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
694 CREATE OR REPLACE FUNCTION update_location(
697 place_country_code varchar(2),
700 rank_address INTEGER,
708 b := deleteLocationArea(partition, place_id);
709 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
710 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
715 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
726 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
727 FOR childplace IN select * from search_name,place_addressline
728 where address_place_id = parent_place_id
729 and search_name.place_id = place_addressline.place_id
731 delete from search_name where place_id = childplace.place_id;
732 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
733 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
735 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
736 childplace.name_vector := childplace.name_vector || to_add;
738 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
739 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
740 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
748 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
751 newkeywords INTEGER[];
752 addedkeywords INTEGER[];
753 removedkeywords INTEGER[];
757 newkeywords := make_keywords(name);
758 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
759 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
760 where place_id = OLD_place_id into addedkeywords, removedkeywords;
762 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
764 IF #removedkeywords > 0 THEN
765 -- abort due to tokens removed
769 IF #addedkeywords > 0 THEN
770 -- short circuit - no changes
774 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
775 RETURN search_name_add_words(OLD_place_id, addedkeywords);
781 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
793 orginalstartnumber INTEGER;
794 originalnumberrange INTEGER;
797 search_place_id BIGINT;
800 havefirstpoint BOOLEAN;
804 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
806 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
807 select nodes from planet_osm_ways where id = wayid INTO waynodes;
808 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
809 IF array_upper(waynodes, 1) IS NOT NULL THEN
811 havefirstpoint := false;
813 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
815 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
816 IF search_place_id IS NULL THEN
817 -- null record of right type
818 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
819 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
820 IF nextnode.geometry IS NULL THEN
821 -- we don't have any information about this point, most likely
822 -- because an excerpt was updated and the node never imported
823 -- because the interpolation is outside the region of the excerpt.
828 select * from placex where place_id = search_place_id INTO nextnode;
831 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
833 IF havefirstpoint THEN
835 -- add point to the line string
836 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
837 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
839 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
841 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
843 IF startnumber != endnumber THEN
845 linestr := linestr || ')';
846 --RAISE WARNING 'linestr %',linestr;
847 linegeo := ST_GeomFromText(linestr,4326);
848 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
849 IF (startnumber > endnumber) THEN
850 housenum := endnumber;
851 endnumber := startnumber;
852 startnumber := housenum;
853 linegeo := ST_Reverse(linegeo);
855 orginalstartnumber := startnumber;
856 originalnumberrange := endnumber - startnumber;
858 -- Too much broken data worldwide for this test to be worth using
859 -- IF originalnumberrange > 500 THEN
860 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
863 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
864 startnumber := startnumber + 1;
867 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
868 startnumber := startnumber + 2;
870 ELSE -- everything else assumed to be 'all'
871 startnumber := startnumber + 1;
875 endnumber := endnumber - 1;
876 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
877 FOR housenum IN startnumber..endnumber BY stepsize LOOP
878 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
879 -- ideally postcodes should move up to the way
880 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
881 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
882 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
883 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
884 newpoints := newpoints + 1;
885 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
888 havefirstpoint := false;
892 IF NOT havefirstpoint THEN
893 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
894 IF startnumber IS NOT NULL AND startnumber > 0 THEN
895 havefirstpoint := true;
896 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
897 prevnode := nextnode;
899 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
905 --RAISE WARNING 'interpolation points % ',newpoints;
912 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
918 country_code VARCHAR(2);
919 default_language VARCHAR(10);
923 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
926 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
927 -- RAISE WARNING 'bad highway %',NEW.osm_id;
930 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
931 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
935 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
936 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
937 RAISE WARNING 'invalid geometry %',NEW.osm_id;
941 IF NEW.osm_type = 'R' THEN
942 -- invalid multipolygons can crash postgis, don't even bother to try!
945 NEW.geometry := ST_buffer(NEW.geometry,0);
946 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
947 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
952 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
954 NEW.place_id := nextval('seq_place');
955 NEW.indexed_status := 1; --STATUS_NEW
957 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
959 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
960 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
962 -- copy 'name' to or from the default language (if there is a default language)
963 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
964 default_language := get_country_language_code(NEW.calculated_country_code);
965 IF default_language IS NOT NULL THEN
966 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
967 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
968 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
969 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
974 IF NEW.admin_level > 15 THEN
975 NEW.admin_level := 15;
978 IF NEW.housenumber IS NOT NULL THEN
979 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
982 IF NEW.osm_type = 'X' THEN
983 -- E'X'ternal records should already be in the right format so do nothing
985 NEW.rank_search := 30;
986 NEW.rank_address := NEW.rank_search;
988 -- By doing in postgres we have the country available to us - currently only used for postcode
989 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
991 IF NEW.postcode IS NULL THEN
992 -- most likely just a part of a multipolygon postcode boundary, throw it away
996 NEW.name := hstore('ref', NEW.postcode);
998 IF NEW.calculated_country_code = 'gb' THEN
1000 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1001 NEW.rank_search := 25;
1002 NEW.rank_address := 5;
1003 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1004 NEW.rank_search := 23;
1005 NEW.rank_address := 5;
1006 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1007 NEW.rank_search := 21;
1008 NEW.rank_address := 5;
1011 ELSEIF NEW.calculated_country_code = 'de' THEN
1013 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1014 NEW.rank_search := 21;
1015 NEW.rank_address := 11;
1019 -- Guess at the postcode format and coverage (!)
1020 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1021 NEW.rank_search := 21;
1022 NEW.rank_address := 11;
1024 -- Does it look splitable into and area and local code?
1025 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1027 IF postcode IS NOT NULL THEN
1028 NEW.rank_search := 25;
1029 NEW.rank_address := 11;
1030 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1031 NEW.rank_search := 21;
1032 NEW.rank_address := 11;
1037 ELSEIF NEW.class = 'place' THEN
1038 IF NEW.type in ('continent') THEN
1039 NEW.rank_search := 2;
1040 NEW.rank_address := NEW.rank_search;
1041 NEW.calculated_country_code := NULL;
1042 ELSEIF NEW.type in ('sea') THEN
1043 NEW.rank_search := 2;
1044 NEW.rank_address := 0;
1045 NEW.calculated_country_code := NULL;
1046 ELSEIF NEW.type in ('country') THEN
1047 NEW.rank_search := 4;
1048 NEW.rank_address := NEW.rank_search;
1049 ELSEIF NEW.type in ('state') THEN
1050 NEW.rank_search := 8;
1051 NEW.rank_address := NEW.rank_search;
1052 ELSEIF NEW.type in ('region') THEN
1053 NEW.rank_search := 18; -- dropped from previous value of 10
1054 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1055 ELSEIF NEW.type in ('county') THEN
1056 NEW.rank_search := 12;
1057 NEW.rank_address := NEW.rank_search;
1058 ELSEIF NEW.type in ('city') THEN
1059 NEW.rank_search := 16;
1060 NEW.rank_address := NEW.rank_search;
1061 ELSEIF NEW.type in ('island') THEN
1062 NEW.rank_search := 17;
1063 NEW.rank_address := 0;
1064 ELSEIF NEW.type in ('town') THEN
1065 NEW.rank_search := 18;
1066 NEW.rank_address := 16;
1067 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1068 NEW.rank_search := 19;
1069 NEW.rank_address := 16;
1070 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1071 NEW.rank_search := 18;
1072 NEW.rank_address := 17;
1073 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1074 NEW.rank_search := 17;
1075 NEW.rank_address := 18;
1076 ELSEIF NEW.type in ('moor') THEN
1077 NEW.rank_search := 17;
1078 NEW.rank_address := 0;
1079 ELSEIF NEW.type in ('national_park') THEN
1080 NEW.rank_search := 18;
1081 NEW.rank_address := 18;
1082 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1083 NEW.rank_search := 20;
1084 NEW.rank_address := NEW.rank_search;
1085 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1086 NEW.rank_search := 20;
1087 NEW.rank_address := 0;
1088 -- Irish townlands, tagged as place=locality and locality=townland
1089 IF (NEW.extratags -> 'locality') = 'townland' THEN
1090 NEW.rank_address := 20;
1092 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1093 NEW.rank_search := 22;
1094 NEW.rank_address := 22;
1095 ELSEIF NEW.type in ('airport','street') THEN
1096 NEW.rank_search := 26;
1097 NEW.rank_address := NEW.rank_search;
1098 ELSEIF NEW.type in ('house','building') THEN
1099 NEW.rank_search := 30;
1100 NEW.rank_address := NEW.rank_search;
1101 ELSEIF NEW.type in ('houses') THEN
1102 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1103 -- insert new point into place for each derived building
1104 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1105 NEW.rank_search := 28;
1106 NEW.rank_address := 0;
1109 ELSEIF NEW.class = 'boundary' THEN
1110 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1111 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1114 NEW.rank_search := NEW.admin_level * 2;
1115 NEW.rank_address := NEW.rank_search;
1116 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1117 NEW.rank_search := 22;
1118 NEW.rank_address := NEW.rank_search;
1119 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1120 NEW.rank_search := 18;
1121 NEW.rank_address := 0;
1122 -- any feature more than 5 square miles is probably worth indexing
1123 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1124 NEW.rank_search := 22;
1125 NEW.rank_address := NEW.rank_search;
1126 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1127 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1128 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1130 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1132 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1134 ELSEIF NEW.class = 'waterway' THEN
1135 NEW.rank_address := 17;
1136 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
1137 NEW.rank_search := 27;
1138 NEW.rank_address := NEW.rank_search;
1139 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1140 NEW.rank_search := 26;
1141 NEW.rank_address := NEW.rank_search;
1142 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1143 NEW.rank_search := 4;
1144 NEW.rank_address := NEW.rank_search;
1145 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1151 IF NEW.rank_search > 30 THEN
1152 NEW.rank_search := 30;
1155 IF NEW.rank_address > 30 THEN
1156 NEW.rank_address := 30;
1159 IF (NEW.extratags -> 'capital') = 'yes' THEN
1160 NEW.rank_search := NEW.rank_search - 1;
1163 -- a country code make no sense below rank 4 (country)
1164 IF NEW.rank_address < 4 THEN
1165 NEW.calculated_country_code := NULL;
1168 -- Block import below rank 22
1169 -- IF NEW.rank_search > 22 THEN
1173 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1175 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1177 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1178 -- Performance: We just can't handle re-indexing for country level changes
1179 IF st_area(NEW.geometry) < 1 THEN
1180 -- mark items within the geometry for re-indexing
1181 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1183 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1184 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1185 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);
1186 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1187 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);
1190 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1192 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1193 IF NEW.type='postcode' THEN
1195 ELSEIF NEW.rank_search < 16 THEN
1197 ELSEIF NEW.rank_search < 18 THEN
1199 ELSEIF NEW.rank_search < 20 THEN
1201 ELSEIF NEW.rank_search = 21 THEN
1203 ELSEIF NEW.rank_search < 24 THEN
1205 ELSEIF NEW.rank_search < 26 THEN
1206 diameter := 0.002; -- 100 to 200 meters
1207 ELSEIF NEW.rank_search < 28 THEN
1208 diameter := 0.001; -- 50 to 100 meters
1210 IF diameter > 0 THEN
1211 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1212 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);
1217 -- add to tables for special search
1218 -- Note: won't work on initial import because the classtype tables
1219 -- do not yet exist. It won't hurt either.
1220 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1221 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1223 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1224 USING NEW.place_id, ST_Centroid(NEW.geometry);
1228 -- IF NEW.rank_search < 26 THEN
1229 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1238 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1243 place_centroid GEOMETRY;
1245 search_maxdistance FLOAT[];
1246 search_mindistance FLOAT[];
1247 address_havelevel BOOLEAN[];
1248 -- search_scores wordscore[];
1249 -- search_scores_pos INTEGER;
1256 relation_members TEXT[];
1258 linkedplacex RECORD;
1259 search_diameter FLOAT;
1260 search_prevdiameter FLOAT;
1261 search_maxrank INTEGER;
1262 address_maxrank INTEGER;
1263 address_street_word_id INTEGER;
1264 parent_place_id_rank BIGINT;
1269 location_rank_search INTEGER;
1270 location_distance FLOAT;
1271 location_parent GEOMETRY;
1272 location_isaddress BOOLEAN;
1276 default_language TEXT;
1277 name_vector INTEGER[];
1278 nameaddress_vector INTEGER[];
1280 linked_node_id BIGINT;
1286 IF OLD.indexed_status = 100 THEN
1287 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1288 delete from placex where place_id = OLD.place_id;
1292 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1296 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1298 --RAISE WARNING '%',NEW.place_id;
1299 --RAISE WARNING '%', NEW;
1301 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1302 -- Silently do nothing
1306 IF OLD.indexed_status != 0 THEN
1307 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1309 NEW.indexed_date = now();
1311 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1312 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1316 IF OLD.indexed_status > 0 THEN
1317 result := deleteSearchName(NEW.partition, NEW.place_id);
1318 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1319 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1320 result := deleteRoad(NEW.partition, NEW.place_id);
1321 result := deleteLocationArea(NEW.partition, NEW.place_id);
1322 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1325 -- Speed up searches - just use the centroid of the feature
1326 -- cheaper but less acurate
1327 place_centroid := ST_PointOnSurface(NEW.geometry);
1328 NEW.centroid := null;
1330 -- reclaculate country and partition
1331 IF NEW.rank_search >= 4 THEN
1332 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1333 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1335 NEW.calculated_country_code := NULL;
1337 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1338 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1340 -- Adding ourselves to the list simplifies address calculations later
1341 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1343 -- What level are we searching from
1344 search_maxrank := NEW.rank_search;
1346 -- Thought this wasn't needed but when we add new languages to the country_name table
1347 -- we need to update the existing names
1348 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1349 default_language := get_country_language_code(NEW.calculated_country_code);
1350 IF default_language IS NOT NULL THEN
1351 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1352 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1353 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1354 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1359 -- Initialise the name vector using our name
1360 name_vector := make_keywords(NEW.name);
1361 nameaddress_vector := '{}'::int[];
1363 -- some tag combinations add a special id for search
1364 tagpairid := get_tagpair(NEW.class,NEW.type);
1365 IF tagpairid IS NOT NULL THEN
1366 name_vector := name_vector + tagpairid;
1370 address_havelevel[i] := false;
1373 NEW.importance := null;
1374 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1375 IF NEW.importance IS NULL THEN
1376 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;
1379 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1381 -- For low level elements we inherit from our parent road
1382 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1384 --RAISE WARNING 'finding street for %', NEW;
1386 NEW.parent_place_id := null;
1388 -- to do that we have to find our parent road
1389 -- Copy data from linked items (points on ways, addr:street links, relations)
1390 -- Note that addr:street links can only be indexed once the street itself is indexed
1391 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1393 -- Is this node part of a relation?
1394 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1396 -- At the moment we only process one type of relation - associatedStreet
1397 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1398 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1399 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1400 --RAISE WARNING 'node in relation %',relation;
1401 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1402 and rank_search = 26 INTO NEW.parent_place_id;
1408 --RAISE WARNING 'x1';
1409 -- Is this node part of a way?
1410 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1411 --RAISE WARNING '%', way;
1412 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1414 --RAISE WARNING '%', location;
1415 -- Way IS a road then we are on it - that must be our road
1416 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1417 --RAISE WARNING 'node in way that is a street %',location;
1418 NEW.parent_place_id := location.place_id;
1421 -- Is the WAY part of a relation
1422 IF NEW.parent_place_id IS NULL THEN
1423 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1425 -- At the moment we only process one type of relation - associatedStreet
1426 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1427 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1428 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1429 --RAISE WARNING 'node in way that is in a relation %',relation;
1430 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1431 and rank_search = 26 INTO NEW.parent_place_id;
1438 -- If the way contains an explicit name of a street copy it
1439 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1440 --RAISE WARNING 'node in way that has a streetname %',location;
1441 NEW.street := location.street;
1444 -- If this way is a street interpolation line then it is probably as good as we are going to get
1445 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1446 -- Try and find a way that is close roughly parellel to this line
1447 FOR relation IN SELECT place_id FROM placex
1448 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1449 and st_geometrytype(location.geometry) in ('ST_LineString')
1450 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1451 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1452 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1454 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1455 NEW.parent_place_id := relation.place_id;
1464 --RAISE WARNING 'x2';
1466 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1467 -- Is this way part of a relation?
1468 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1470 -- At the moment we only process one type of relation - associatedStreet
1471 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1472 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1473 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1474 --RAISE WARNING 'way that is in a relation %',relation;
1475 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1476 and rank_search = 26 INTO NEW.parent_place_id;
1483 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1485 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1486 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1487 IF address_street_word_id IS NOT NULL THEN
1488 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1489 NEW.parent_place_id := location.place_id;
1494 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1495 -- Still nothing, just use the nearest road
1496 IF NEW.parent_place_id IS NULL THEN
1497 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1498 NEW.parent_place_id := location.place_id;
1503 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1505 -- If we didn't find any road fallback to standard method
1506 IF NEW.parent_place_id IS NOT NULL THEN
1508 -- Add the street to the address as zero distance to force to front of list
1509 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1510 address_havelevel[26] := true;
1512 -- Import address details from parent, reclculating distance in process
1513 -- INSERT INTO place_addressline select NEW.place_id, x.address_place_id, x.fromarea, x.isaddress, ST_distance(NEW.geometry, placex.geometry), placex.rank_address
1514 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1515 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1517 -- Get the details of the parent road
1518 select * from search_name where place_id = NEW.parent_place_id INTO location;
1519 NEW.calculated_country_code := location.country_code;
1521 --RAISE WARNING '%', NEW.name;
1522 -- If there is no name it isn't searchable, don't bother to create a search record
1523 IF NEW.name is NULL THEN
1527 -- Merge address from parent
1528 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1530 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1531 -- Just be happy with inheriting from parent road only
1533 IF NEW.rank_search <= 25 THEN
1534 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1537 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);
1544 -- RAISE WARNING ' INDEXING Started:';
1545 -- RAISE WARNING ' INDEXING: %',NEW;
1547 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1549 -- see if we have any special relation members
1550 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1552 -- RAISE WARNING 'get_osm_rel_members, label';
1553 IF relation_members IS NOT NULL THEN
1554 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1556 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1557 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1559 -- If we don't already have one use this as the centre point of the geometry
1560 IF NEW.centroid IS NULL THEN
1561 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1564 -- merge in the label name, re-init word vector
1565 IF NOT linkedPlacex.name IS NULL THEN
1566 NEW.name := linkedPlacex.name || NEW.name;
1567 name_vector := make_keywords(NEW.name);
1570 -- merge in extra tags
1571 IF NOT linkedPlacex.extratags IS NULL THEN
1572 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1575 -- mark the linked place (excludes from search results)
1576 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1582 IF NEW.centroid IS NULL THEN
1584 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1586 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1587 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1589 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1590 -- But that can be fixed by explicitly setting the label in the data
1591 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1592 AND NEW.rank_address = linkedPlacex.rank_address THEN
1595 -- If we don't already have one use this as the centre point of the geometry
1596 IF NEW.centroid IS NULL THEN
1597 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1600 -- merge in the name, re-init word vector
1601 IF NOT linkedPlacex.name IS NULL THEN
1602 NEW.name := linkedPlacex.name || NEW.name;
1603 name_vector := make_keywords(NEW.name);
1606 -- merge in extra tags
1607 IF NOT linkedPlacex.extratags IS NULL THEN
1608 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1611 -- mark the linked place (excludes from search results)
1612 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1614 -- keep a note of the node id in case we need it for wikipedia in a bit
1615 linked_node_id := linkedPlacex.osm_id;
1625 -- not found one yet? how about doing a name search
1626 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1628 FOR linkedPlacex IN select placex.* from placex WHERE
1629 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1630 AND placex.rank_address = NEW.rank_address
1631 AND placex.place_id != NEW.place_id
1632 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1633 AND st_covers(NEW.geometry, placex.geometry)
1636 -- If we don't already have one use this as the centre point of the geometry
1637 IF NEW.centroid IS NULL THEN
1638 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1641 -- merge in the name, re-init word vector
1642 NEW.name := linkedPlacex.name || NEW.name;
1643 name_vector := make_keywords(NEW.name);
1645 -- merge in extra tags
1646 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1648 -- mark the linked place (excludes from search results)
1649 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1651 -- keep a note of the node id in case we need it for wikipedia in a bit
1652 linked_node_id := linkedPlacex.osm_id;
1656 IF NEW.centroid IS NOT NULL THEN
1657 place_centroid := NEW.centroid;
1660 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1661 IF NEW.importance is null THEN
1662 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1664 -- Still null? how about looking it up by the node id
1665 IF NEW.importance IS NULL THEN
1666 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;
1671 -- make sure all names are in the word table
1672 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1673 perform create_country(NEW.name, lower(NEW.country_code));
1676 NEW.parent_place_id = 0;
1677 parent_place_id_rank = 0;
1679 -- convert isin to array of tokenids
1680 isin_tokens := '{}'::int[];
1681 IF NEW.isin IS NOT NULL THEN
1682 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1683 IF array_upper(isin, 1) IS NOT NULL THEN
1684 FOR i IN 1..array_upper(isin, 1) LOOP
1685 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1686 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1687 isin_tokens := isin_tokens || address_street_word_id;
1692 IF NEW.postcode IS NOT NULL THEN
1693 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1694 IF array_upper(isin, 1) IS NOT NULL THEN
1695 FOR i IN 1..array_upper(isin, 1) LOOP
1696 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1697 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1698 isin_tokens := isin_tokens || address_street_word_id;
1703 -- RAISE WARNING 'ISIN: %', isin_tokens;
1705 -- Process area matches
1706 location_rank_search := 0;
1707 location_distance := 0;
1708 location_parent := NULL;
1709 -- added ourself as address already
1710 address_havelevel[NEW.rank_address] := true;
1711 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1712 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1714 --RAISE WARNING ' AREA: %',location;
1716 IF location.rank_address != location_rank_search THEN
1717 location_rank_search := location.rank_address;
1718 location_distance := location.distance * 1.5;
1721 IF location.distance < location_distance OR NOT location.isguess THEN
1723 location_isaddress := NOT address_havelevel[location.rank_address];
1724 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1725 location_isaddress := ST_Contains(location_parent,location.centroid);
1728 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1729 -- Add it to the list of search terms
1730 IF location.rank_search > 4 THEN
1731 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1733 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1735 IF location_isaddress THEN
1736 address_havelevel[location.rank_address] := true;
1737 IF NOT location.isguess THEN
1738 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1742 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1744 IF location.rank_address > parent_place_id_rank THEN
1745 NEW.parent_place_id = location.place_id;
1746 parent_place_id_rank = location.rank_address;
1753 -- try using the isin value to find parent places
1754 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1755 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1756 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1757 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1759 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1761 --RAISE WARNING ' ISIN: %',location;
1763 IF location.rank_search > 4 THEN
1764 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1765 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1766 address_havelevel[location.rank_address] := true;
1768 IF location.rank_address > parent_place_id_rank THEN
1769 NEW.parent_place_id = location.place_id;
1770 parent_place_id_rank = location.rank_address;
1780 -- for long ways we should add search terms for the entire length
1781 IF st_length(NEW.geometry) > 0.05 THEN
1783 location_rank_search := 0;
1784 location_distance := 0;
1786 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1788 IF location.rank_address != location_rank_search THEN
1789 location_rank_search := location.rank_address;
1790 location_distance := location.distance * 1.5;
1793 IF location.rank_search > 4 AND location.distance < location_distance THEN
1795 -- Add it to the list of search terms
1796 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1797 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1805 -- if we have a name add this to the name search table
1806 IF NEW.name IS NOT NULL THEN
1808 IF NEW.rank_search <= 25 THEN
1809 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1812 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1813 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1816 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);
1818 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid);
1821 -- If we've not managed to pick up a better one - default centroid
1822 IF NEW.centroid IS NULL THEN
1823 NEW.centroid := place_centroid;
1833 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1839 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1841 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1842 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1843 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1844 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1846 IF OLD.rank_address < 30 THEN
1848 -- mark everything linked to this place for re-indexing
1849 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1850 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1851 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1853 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1854 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1856 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1857 b := deleteRoad(OLD.partition, OLD.place_id);
1859 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1860 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1861 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1865 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1867 IF OLD.rank_address < 26 THEN
1868 b := deleteLocationArea(OLD.partition, OLD.place_id);
1871 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1873 IF OLD.name is not null THEN
1874 b := deleteSearchName(OLD.partition, OLD.place_id);
1877 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1879 DELETE FROM place_addressline where place_id = OLD.place_id;
1881 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1883 -- remove from tables for special search
1884 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1885 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1887 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1890 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1898 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1904 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1906 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1907 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1908 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1913 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;
1921 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1926 existingplacex RECORD;
1927 existinggeometry GEOMETRY;
1928 existingplace_id BIGINT;
1933 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1934 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1936 IF FALSE and NEW.osm_type = 'R' THEN
1937 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;
1938 --DEBUG: RAISE WARNING '%', existingplacex;
1941 -- Just block these - lots and pointless
1942 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1945 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1949 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
1950 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1951 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1952 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1956 -- Patch in additional country names
1957 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1958 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1961 -- Have we already done this place?
1962 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;
1964 -- Get the existing place_id
1965 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;
1967 -- Handle a place changing type by removing the old data
1968 -- My generated 'place' types are causing havok because they overlap with real keys
1969 -- TODO: move them to their own special purpose key/class to avoid collisions
1970 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1971 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses');
1974 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1975 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1978 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1979 AND st_area(existing.geometry) > 0.02
1980 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1981 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1983 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1984 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1988 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1989 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1991 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry
1992 IF existingplacex.osm_type IS NULL THEN
1994 IF existing.osm_type IS NOT NULL THEN
1995 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1998 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1999 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2000 street, isin, postcode, country_code, extratags, geometry)
2001 values (NEW.osm_type
2016 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2021 -- Various ways to do the update
2023 -- Debug, what's changed?
2025 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2026 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2028 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2029 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2031 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2032 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2034 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2035 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2037 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2038 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2040 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2041 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2045 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2046 IF existing.geometry::text != NEW.geometry::text
2047 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2048 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2051 -- Get the version of the geometry actually used (in placex table)
2052 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;
2054 -- Performance limit
2055 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2057 -- 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
2058 update placex set indexed_status = 2 where indexed_status = 0 and
2059 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2060 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2061 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2063 update placex set indexed_status = 2 where indexed_status = 0 and
2064 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2065 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2066 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2072 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2073 IF FALSE AND existingplacex.rank_search < 26
2074 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2075 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2076 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2077 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2078 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2079 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2082 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2084 IF st_area(NEW.geometry) < 0.5 THEN
2085 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2086 and placex.place_id = place_addressline.place_id and indexed_status = 0
2087 and (rank_search < 28 or name is not null);
2094 -- Anything else has changed - reindex the lot
2095 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2096 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2097 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2098 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2099 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2100 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2102 -- performance, can't take the load of re-indexing a whole country / huge area
2103 IF st_area(NEW.geometry) < 0.5 THEN
2104 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2105 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2112 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2113 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2114 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2115 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2116 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2117 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2118 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2119 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2120 OR existing.geometry::text != NEW.geometry::text
2125 housenumber = NEW.housenumber,
2126 street = NEW.street,
2128 postcode = NEW.postcode,
2129 country_code = NEW.country_code,
2130 extratags = NEW.extratags,
2131 geometry = NEW.geometry
2132 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2136 housenumber = NEW.housenumber,
2137 street = NEW.street,
2139 postcode = NEW.postcode,
2140 country_code = NEW.country_code,
2141 parent_place_id = null,
2142 extratags = NEW.extratags,
2144 geometry = NEW.geometry
2145 where place_id = existingplacex.place_id;
2149 -- Abort the add (we modified the existing place instead)
2153 $$ LANGUAGE plpgsql;
2155 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2162 IF name is null THEN
2166 search := languagepref;
2168 FOR j IN 1..array_upper(search, 1) LOOP
2169 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2170 return trim(name->search[j]);
2174 -- anything will do as a fallback - just take the first name type thing there is
2175 search := avals(name);
2179 LANGUAGE plpgsql IMMUTABLE;
2181 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2184 searchnodes INTEGER[];
2189 searchnodes := '{}';
2190 FOR j IN 1..array_upper(way_ids, 1) LOOP
2192 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2194 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2195 searchnodes := searchnodes || location.nodes;
2200 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2203 LANGUAGE plpgsql IMMUTABLE;
2205 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2216 search := ARRAY['ref'];
2219 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2222 select rank_address,name,distance,length(name::text) as namelength
2223 from place_addressline join placex on (address_place_id = placex.place_id)
2224 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2225 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2227 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2228 FOR j IN 1..array_upper(search, 1) LOOP
2229 FOR k IN 1..array_upper(location.name, 1) LOOP
2230 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
2231 result[(100 - location.rank_address)] := trim(location.name[k].value);
2232 found := location.rank_address;
2239 RETURN array_to_string(result,', ');
2244 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2256 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2257 currresult := trim(get_name_by_language(location.name, languagepref));
2258 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2259 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2260 prevresult := currresult;
2264 RETURN array_to_string(result,', ');
2269 DROP TYPE addressline CASCADE;
2270 create type addressline as (
2277 admin_level INTEGER,
2280 rank_address INTEGER,
2284 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2287 for_place_id BIGINT;
2292 countrylocation RECORD;
2293 searchcountrycode varchar(2);
2294 searchhousenumber TEXT;
2295 searchhousename HSTORE;
2296 searchrankaddress INTEGER;
2297 searchpostcode TEXT;
2304 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2305 WHERE place_id = in_place_id
2306 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2308 IF for_place_id IS NULL THEN
2309 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2310 WHERE place_id = in_place_id
2311 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2314 IF for_place_id IS NULL THEN
2315 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2316 WHERE place_id = in_place_id and rank_address = 30
2317 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2320 IF for_place_id IS NULL THEN
2321 for_place_id := in_place_id;
2322 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2323 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2326 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2329 hadcountry := false;
2331 select placex.place_id, osm_type, osm_id,
2332 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2333 class, type, admin_level, true as fromarea, true as isaddress,
2334 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2335 0 as distance, calculated_country_code
2337 where place_id = for_place_id
2339 --RAISE WARNING '%',location;
2340 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2341 searchcountrycode := location.calculated_country_code;
2343 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2344 location.isaddress := FALSE;
2346 IF location.rank_address = 4 AND location.isaddress THEN
2349 IF location.rank_address < 4 AND NOT hadcountry THEN
2350 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2351 IF countryname IS NOT NULL THEN
2352 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2353 RETURN NEXT countrylocation;
2356 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2357 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2358 location.distance)::addressline;
2359 RETURN NEXT countrylocation;
2360 found := location.rank_address;
2364 select placex.place_id, osm_type, osm_id,
2365 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2366 class, type, admin_level, fromarea, isaddress,
2367 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,
2368 distance,calculated_country_code
2369 from place_addressline join placex on (address_place_id = placex.place_id)
2370 where place_addressline.place_id = for_place_id
2371 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2372 and address_place_id != for_place_id
2373 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2374 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2376 --RAISE WARNING '%',location;
2377 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2378 searchcountrycode := location.calculated_country_code;
2380 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2381 location.isaddress := FALSE;
2383 IF location.rank_address = 4 AND location.isaddress THEN
2386 IF location.rank_address < 4 AND NOT hadcountry THEN
2387 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2388 IF countryname IS NOT NULL THEN
2389 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2390 RETURN NEXT countrylocation;
2393 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2394 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2395 location.distance)::addressline;
2396 RETURN NEXT countrylocation;
2397 found := location.rank_address;
2401 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2402 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2403 IF countryname IS NOT NULL THEN
2404 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2405 RETURN NEXT location;
2409 IF searchcountrycode IS NOT NULL THEN
2410 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2411 RETURN NEXT location;
2414 IF searchhousename IS NOT NULL THEN
2415 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2416 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2417 RETURN NEXT location;
2420 IF searchhousenumber IS NOT NULL THEN
2421 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2422 RETURN NEXT location;
2425 IF searchpostcode IS NOT NULL THEN
2426 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2427 RETURN NEXT location;
2435 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2438 result place_boundingbox;
2439 numfeatures integer;
2441 select * from place_boundingbox into result where place_id = search_place_id;
2442 IF result.place_id IS NULL THEN
2443 -- remove isaddress = true because if there is a matching polygon it always wins
2444 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2445 insert into place_boundingbox select place_id,
2446 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2447 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2448 numfeatures, ST_Area(geometry),
2449 geometry as area from location_area where place_id = search_place_id;
2450 select * from place_boundingbox into result where place_id = search_place_id;
2452 IF result.place_id IS NULL THEN
2454 insert into place_boundingbox select address_place_id,
2455 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2456 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2457 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2458 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2459 from (select * from place_addressline where address_place_id = search_place_id order by cached_rank_address limit 4000) as place_addressline join placex using (place_id)
2460 where address_place_id = search_place_id
2461 -- and (isaddress = true OR place_id = search_place_id)
2462 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2463 group by address_place_id limit 1;
2464 select * from place_boundingbox into result where place_id = search_place_id;
2471 -- don't do the operation if it would be slow
2472 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2475 result place_boundingbox;
2476 numfeatures integer;
2479 select * from place_boundingbox into result where place_id = search_place_id;
2480 IF result IS NULL AND rank > 14 THEN
2481 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2482 insert into place_boundingbox select place_id,
2483 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2484 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2485 numfeatures, ST_Area(geometry),
2486 geometry as area from location_area where place_id = search_place_id;
2487 select * from place_boundingbox into result where place_id = search_place_id;
2489 IF result IS NULL THEN
2490 select rank_search from placex where place_id = search_place_id into rank;
2493 insert into place_boundingbox select address_place_id,
2494 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2495 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2496 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2497 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2498 from place_addressline join placex using (place_id)
2499 where address_place_id = search_place_id
2500 and (isaddress = true OR place_id = search_place_id)
2501 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2502 group by address_place_id limit 1;
2503 select * from place_boundingbox into result where place_id = search_place_id;
2511 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2514 result place_boundingbox;
2515 numfeatures integer;
2519 housenumber = place.housenumber,
2520 street = place.street,
2522 postcode = place.postcode,
2523 country_code = place.country_code,
2524 parent_place_id = null
2526 where placex.place_id = search_place_id
2527 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2528 and place.class = placex.class and place.type = placex.type;
2529 update placex set indexed_status = 2 where place_id = search_place_id;
2530 update placex set indexed_status = 0 where place_id = search_place_id;
2536 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2542 ELSEIF rank < 4 THEN
2544 ELSEIF rank < 8 THEN
2546 ELSEIF rank < 12 THEN
2548 ELSEIF rank < 16 THEN
2550 ELSEIF rank = 16 THEN
2552 ELSEIF rank = 17 THEN
2553 RETURN 'Town / Island';
2554 ELSEIF rank = 18 THEN
2555 RETURN 'Village / Hamlet';
2556 ELSEIF rank = 20 THEN
2558 ELSEIF rank = 21 THEN
2559 RETURN 'Postcode Area';
2560 ELSEIF rank = 22 THEN
2561 RETURN 'Croft / Farm / Locality / Islet';
2562 ELSEIF rank = 23 THEN
2563 RETURN 'Postcode Area';
2564 ELSEIF rank = 25 THEN
2565 RETURN 'Postcode Point';
2566 ELSEIF rank = 26 THEN
2567 RETURN 'Street / Major Landmark';
2568 ELSEIF rank = 27 THEN
2569 RETURN 'Minory Street / Path';
2570 ELSEIF rank = 28 THEN
2571 RETURN 'House / Building';
2573 RETURN 'Other: '||rank;
2580 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2586 ELSEIF rank < 2 THEN
2588 ELSEIF rank < 4 THEN
2590 ELSEIF rank = 5 THEN
2592 ELSEIF rank < 8 THEN
2594 ELSEIF rank < 12 THEN
2596 ELSEIF rank < 16 THEN
2598 ELSEIF rank = 16 THEN
2600 ELSEIF rank = 17 THEN
2601 RETURN 'Town / Village / Hamlet';
2602 ELSEIF rank = 20 THEN
2604 ELSEIF rank = 21 THEN
2605 RETURN 'Postcode Area';
2606 ELSEIF rank = 22 THEN
2607 RETURN 'Croft / Farm / Locality / Islet';
2608 ELSEIF rank = 23 THEN
2609 RETURN 'Postcode Area';
2610 ELSEIF rank = 25 THEN
2611 RETURN 'Postcode Point';
2612 ELSEIF rank = 26 THEN
2613 RETURN 'Street / Major Landmark';
2614 ELSEIF rank = 27 THEN
2615 RETURN 'Minory Street / Path';
2616 ELSEIF rank = 28 THEN
2617 RETURN 'House / Building';
2619 RETURN 'Other: '||rank;
2626 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2633 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2634 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2641 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2649 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2651 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2652 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2654 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2662 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2663 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2668 place_centroid GEOMETRY;
2669 out_partition INTEGER;
2670 out_parent_place_id BIGINT;
2672 address_street_word_id INTEGER;
2677 place_centroid := ST_Centroid(pointgeo);
2678 out_partition := get_partition(place_centroid, in_countrycode);
2679 out_parent_place_id := null;
2681 address_street_word_id := get_name_id(make_standard_name(in_street));
2682 IF address_street_word_id IS NOT NULL THEN
2683 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2684 out_parent_place_id := location.place_id;
2688 IF out_parent_place_id IS NULL THEN
2689 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2690 out_parent_place_id := location.place_id;
2694 out_postcode := in_postcode;
2695 IF out_postcode IS NULL THEN
2696 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2698 IF out_postcode IS NULL THEN
2699 out_postcode := getNearestPostcode(out_partition, place_centroid);
2703 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2704 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2705 newpoints := newpoints + 1;
2712 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2719 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2720 IF members[i+1] = member THEN
2721 result := result || members[i];
2730 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2736 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2737 IF members[i+1] = ANY(memberLabels) THEN
2738 RETURN NEXT members[i];
2747 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2748 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2750 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2751 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
2752 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2753 ), '') AS bytea), 'UTF8');
2755 LANGUAGE SQL IMMUTABLE STRICT;
2757 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2761 RETURN decode_url_part(p);
2763 WHEN others THEN return null;
2766 LANGUAGE plpgsql IMMUTABLE;
2768 DROP TYPE wikipedia_article_match CASCADE;
2769 create type wikipedia_article_match as (
2775 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2781 wiki_article_title TEXT;
2782 wiki_article_language TEXT;
2783 result wikipedia_article_match;
2785 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'];
2787 WHILE langs[i] IS NOT NULL LOOP
2788 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2789 IF wiki_article is not null THEN
2790 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2791 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2792 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2793 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2794 wiki_article := replace(wiki_article,' ','_');
2795 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2796 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2797 wiki_article_title := trim(wiki_article);
2798 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;
2800 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2803 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2804 from wikipedia_article
2805 where language = wiki_article_language and
2806 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2808 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2809 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2810 where wikipedia_redirect.language = wiki_article_language and
2811 (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'\\',''))
2812 order by importance desc limit 1 INTO result;
2814 IF result.language is not null THEN
2825 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2826 RETURNS SETOF GEOMETRY
2840 remainingdepth INTEGER;
2845 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2847 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2848 RETURN NEXT geometry;
2852 remainingdepth := maxdepth - 1;
2853 area := ST_AREA(geometry);
2854 IF remainingdepth < 1 OR area < maxarea THEN
2855 RETURN NEXT geometry;
2859 xmin := st_xmin(geometry);
2860 xmax := st_xmax(geometry);
2861 ymin := st_ymin(geometry);
2862 ymax := st_ymax(geometry);
2863 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2865 -- if the geometry completely covers the box don't bother to slice any more
2866 IF ST_AREA(secbox) = area THEN
2867 RETURN NEXT geometry;
2871 xmid := (xmin+xmax)/2;
2872 ymid := (ymin+ymax)/2;
2875 FOR seg IN 1..4 LOOP
2878 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2881 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2884 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2887 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2890 IF st_intersects(geometry, secbox) THEN
2891 secgeo := st_intersection(geometry, secbox);
2892 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2893 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2894 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2896 RETURN NEXT geo.geom;
2908 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2909 RETURNS SETOF GEOMETRY
2914 -- 10000000000 is ~~ 1x1 degree
2915 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2916 RETURN NEXT geo.geom;
2924 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2928 osmtype character(1);
2932 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2933 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2934 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2935 -- force delete from place/placex by making it a very small geometry
2936 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;
2937 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2944 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2952 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2953 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2954 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2955 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2956 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2957 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null);
2958 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2959 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null);
2965 ELSEIF rank < 18 THEN
2967 ELSEIF rank < 20 THEN
2969 ELSEIF rank = 21 THEN
2971 ELSEIF rank < 24 THEN
2973 ELSEIF rank < 26 THEN
2974 diameter := 0.002; -- 100 to 200 meters
2975 ELSEIF rank < 28 THEN
2976 diameter := 0.001; -- 50 to 100 meters
2978 IF diameter > 0 THEN
2979 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);