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 (
8 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
15 LANGUAGE plpgsql IMMUTABLE;
17 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
23 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
29 LANGUAGE plpgsql IMMUTABLE;
31 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
37 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
38 NEWgeometry := ST_buffer(NEWgeometry,0);
39 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
40 RETURN ST_SetSRID(ST_Point(0,0),4326);
46 LANGUAGE plpgsql IMMUTABLE;
48 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
53 -- RAISE WARNING '%',place;
54 NEWgeometry := ST_PointOnSurface(place);
55 -- 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
56 -- NEWgeometry := ST_buffer(NEWgeometry,0);
57 -- 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
61 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
64 LANGUAGE plpgsql IMMUTABLE;
66 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
67 AS '{modulepath}/nominatim.so', 'transliteration'
68 LANGUAGE c IMMUTABLE STRICT;
70 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
71 AS '{modulepath}/nominatim.so', 'gettokenstring'
72 LANGUAGE c IMMUTABLE STRICT;
74 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
79 o := gettokenstring(transliteration(name));
80 RETURN trim(substr(o,1,length(o)));
83 LANGUAGE 'plpgsql' IMMUTABLE;
85 -- returns NULL if the word is too common
86 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
91 return_word_id INTEGER;
94 lookup_token := trim(lookup_word);
95 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;
96 IF return_word_id IS NULL THEN
97 return_word_id := nextval('seq_word');
98 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
100 IF count > get_maxwordfreq() THEN
101 return_word_id := NULL;
104 RETURN return_word_id;
109 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
114 return_word_id INTEGER;
116 lookup_token := ' '||trim(lookup_word);
117 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
118 IF return_word_id IS NULL THEN
119 return_word_id := nextval('seq_word');
120 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
122 RETURN return_word_id;
127 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
132 return_word_id INTEGER;
134 lookup_token := ' '||trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
168 return_word_id INTEGER;
170 lookup_token := lookup_class||'='||lookup_type;
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := lookup_class||'='||lookup_type;
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
190 RETURN return_word_id;
195 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
200 return_word_id INTEGER;
202 lookup_token := ' '||trim(lookup_word);
203 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;
204 IF return_word_id IS NULL THEN
205 return_word_id := nextval('seq_word');
206 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
208 RETURN return_word_id;
213 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
218 nospace_lookup_token TEXT;
219 return_word_id INTEGER;
221 lookup_token := ' '||trim(lookup_word);
222 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
223 IF return_word_id IS NULL THEN
224 return_word_id := nextval('seq_word');
225 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
226 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
227 -- IF ' '||nospace_lookup_token != lookup_token THEN
228 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
231 RETURN return_word_id;
236 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
241 RETURN getorcreate_name_id(lookup_word, '');
246 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
251 return_word_id INTEGER;
253 lookup_token := trim(lookup_word);
254 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
255 RETURN return_word_id;
258 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
265 return_word_id INTEGER;
267 lookup_token := ' '||trim(lookup_word);
268 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
269 RETURN return_word_id;
272 LANGUAGE plpgsql IMMUTABLE;
274 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
279 return_word_ids INTEGER[];
281 lookup_token := ' '||trim(lookup_word);
282 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
283 RETURN return_word_ids;
286 LANGUAGE plpgsql IMMUTABLE;
288 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
295 IF array_upper(a, 1) IS NULL THEN
298 IF array_upper(b, 1) IS NULL THEN
302 FOR i IN 1..array_upper(b, 1) LOOP
303 IF NOT (ARRAY[b[i]] <@ r) THEN
310 LANGUAGE plpgsql IMMUTABLE;
312 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
321 FOR item IN SELECT (each(src)).* LOOP
323 s := make_standard_name(item.value);
324 w := getorcreate_country(s, lookup_country_code);
326 words := regexp_split_to_array(item.value, E'[,;()]');
327 IF array_upper(words, 1) != 1 THEN
328 FOR j IN 1..array_upper(words, 1) LOOP
329 s := make_standard_name(words[j]);
331 w := getorcreate_country(s, lookup_country_code);
340 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
350 result := '{}'::INTEGER[];
352 FOR item IN SELECT (each(src)).* LOOP
354 s := make_standard_name(item.value);
356 w := getorcreate_name_id(s, item.value);
358 IF not(ARRAY[w] <@ result) THEN
359 result := result || w;
362 w := getorcreate_word_id(s);
364 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
365 result := result || w;
368 words := string_to_array(s, ' ');
369 IF array_upper(words, 1) IS NOT NULL THEN
370 FOR j IN 1..array_upper(words, 1) LOOP
371 IF (words[j] != '') THEN
372 w = getorcreate_word_id(words[j]);
373 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
374 result := result || w;
380 words := regexp_split_to_array(item.value, E'[,;()]');
381 IF array_upper(words, 1) != 1 THEN
382 FOR j IN 1..array_upper(words, 1) LOOP
383 s := make_standard_name(words[j]);
385 w := getorcreate_word_id(s);
386 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
387 result := result || w;
393 s := regexp_replace(item.value, '市$', '');
394 IF s != item.value THEN
395 s := make_standard_name(s);
397 w := getorcreate_name_id(s, item.value);
398 IF NOT (ARRAY[w] <@ result) THEN
399 result := result || w;
409 LANGUAGE plpgsql IMMUTABLE;
411 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
421 result := '{}'::INTEGER[];
423 s := make_standard_name(src);
424 w := getorcreate_name_id(s, src);
426 IF NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 w := getorcreate_word_id(s);
432 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
433 result := result || w;
436 words := string_to_array(s, ' ');
437 IF array_upper(words, 1) IS NOT NULL THEN
438 FOR j IN 1..array_upper(words, 1) LOOP
439 IF (words[j] != '') THEN
440 w = getorcreate_word_id(words[j]);
441 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
448 words := regexp_split_to_array(src, E'[,;()]');
449 IF array_upper(words, 1) != 1 THEN
450 FOR j IN 1..array_upper(words, 1) LOOP
451 s := make_standard_name(words[j]);
453 w := getorcreate_word_id(s);
454 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
455 result := result || w;
461 s := regexp_replace(src, '市$', '');
463 s := make_standard_name(s);
465 w := getorcreate_name_id(s, src);
466 IF NOT (ARRAY[w] <@ result) THEN
467 result := result || w;
475 LANGUAGE plpgsql IMMUTABLE;
477 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
484 IF (wordscores is null OR words is null) THEN
489 FOR idxword in 1 .. array_upper(words, 1) LOOP
490 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
491 IF wordscores[idxscores].word = words[idxword] THEN
492 result := result + wordscores[idxscores].score;
500 LANGUAGE plpgsql IMMUTABLE;
502 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
505 place_centre GEOMETRY;
508 place_centre := ST_PointOnSurface(place);
510 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
512 -- Try for a OSM polygon
513 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
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
520 -- Try for OSM fallback data
521 -- The order is to deal with places like HongKong that are 'states' within another polygon
522 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
524 RETURN nearcountry.country_code;
527 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
529 -- Natural earth data
530 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
532 RETURN nearcountry.country_code;
535 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
538 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
540 RETURN nearcountry.country_code;
543 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
545 -- Natural earth data
546 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
548 RETURN nearcountry.country_code;
551 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
552 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
554 -- RETURN nearcountry.country_code;
557 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
559 -- Still not in a country - try nearest within ~12 miles of a country
560 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
561 -- order by st_distance(geometry, place) limit 1
563 -- RETURN nearcountry.country_code;
569 LANGUAGE plpgsql IMMUTABLE;
571 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
576 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
578 RETURN lower(nearcountry.country_default_language_code);
583 LANGUAGE plpgsql IMMUTABLE;
585 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
590 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
592 RETURN lower(nearcountry.country_default_language_codes);
597 LANGUAGE plpgsql IMMUTABLE;
599 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
604 FOR nearcountry IN select partition from country_name where country_code = in_country_code
606 RETURN nearcountry.partition;
611 LANGUAGE plpgsql IMMUTABLE;
613 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
617 DELETE FROM location_area where place_id = OLD_place_id;
618 -- TODO:location_area
624 CREATE OR REPLACE FUNCTION add_location(
626 country_code varchar(2),
630 rank_address INTEGER,
645 IF rank_search > 25 THEN
646 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
649 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
651 x := deleteLocationArea(partition, place_id, rank_search);
654 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
657 centroid := ST_Centroid(geometry);
659 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
660 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
663 ELSEIF rank_search < 26 THEN
666 IF rank_address = 0 THEN
668 ELSEIF rank_search <= 14 THEN
670 ELSEIF rank_search <= 15 THEN
672 ELSEIF rank_search <= 16 THEN
674 ELSEIF rank_search <= 17 THEN
676 ELSEIF rank_search <= 21 THEN
678 ELSEIF rank_search = 25 THEN
682 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
684 secgeo := ST_Buffer(geometry, diameter);
685 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
690 secgeo := ST_Buffer(geometry, 0.0002);
691 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
694 secgeo := ST_Buffer(geometry, 0.001);
695 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
704 CREATE OR REPLACE FUNCTION update_location(
707 place_country_code varchar(2),
710 rank_address INTEGER,
718 b := deleteLocationArea(partition, place_id, rank_search);
719 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
720 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
725 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
736 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
737 FOR childplace IN select * from search_name,place_addressline
738 where address_place_id = parent_place_id
739 and search_name.place_id = place_addressline.place_id
741 delete from search_name where place_id = childplace.place_id;
742 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
743 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
745 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
746 childplace.name_vector := childplace.name_vector || to_add;
748 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
749 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
750 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
758 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
761 newkeywords INTEGER[];
762 addedkeywords INTEGER[];
763 removedkeywords INTEGER[];
767 newkeywords := make_keywords(name);
768 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
769 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
770 where place_id = OLD_place_id into addedkeywords, removedkeywords;
772 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
774 IF #removedkeywords > 0 THEN
775 -- abort due to tokens removed
779 IF #addedkeywords > 0 THEN
780 -- short circuit - no changes
784 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
785 RETURN search_name_add_words(OLD_place_id, addedkeywords);
791 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
803 orginalstartnumber INTEGER;
804 originalnumberrange INTEGER;
807 search_place_id BIGINT;
810 havefirstpoint BOOLEAN;
814 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
816 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
817 select nodes from planet_osm_ways where id = wayid INTO waynodes;
818 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
819 IF array_upper(waynodes, 1) IS NOT NULL THEN
821 havefirstpoint := false;
823 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
825 -- If there is a place of a type other than place/house, use that because
826 -- it is guaranteed to be the original node. For place/house types use the
827 -- one with the smallest id because the original node was created first.
828 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
829 select place_id from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and indexed_status < 100 order by (type = 'house'),place_id limit 1 INTO search_place_id;
830 IF search_place_id IS NULL THEN
831 -- if no such node exists, create a record of the right type
832 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and type = 'house' limit 1 INTO nextnode;
833 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
834 IF nextnode.geometry IS NULL THEN
835 -- we don't have any information about this point, most likely
836 -- because an excerpt was updated and the node never imported
837 -- because the interpolation is outside the region of the excerpt.
842 select * from placex where place_id = search_place_id INTO nextnode;
845 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
847 IF havefirstpoint THEN
849 -- add point to the line string
850 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
851 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
853 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
855 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
857 IF startnumber != endnumber THEN
859 linestr := linestr || ')';
860 --RAISE WARNING 'linestr %',linestr;
861 linegeo := ST_GeomFromText(linestr,4326);
862 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
863 IF (startnumber > endnumber) THEN
864 housenum := endnumber;
865 endnumber := startnumber;
866 startnumber := housenum;
867 linegeo := ST_Reverse(linegeo);
869 orginalstartnumber := startnumber;
870 originalnumberrange := endnumber - startnumber;
872 -- Too much broken data worldwide for this test to be worth using
873 -- IF originalnumberrange > 500 THEN
874 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
877 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
878 startnumber := startnumber + 1;
881 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
882 startnumber := startnumber + 2;
884 ELSE -- everything else assumed to be 'all'
885 startnumber := startnumber + 1;
889 endnumber := endnumber - 1;
890 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
891 FOR housenum IN startnumber..endnumber BY stepsize LOOP
892 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
893 -- ideally postcodes should move up to the way
894 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, addr_place, isin, postcode,
895 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
896 values ('N',prevnode.osm_id, 'place', 'house', prevnode.admin_level, housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
897 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_LineInterpolatePoint(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
898 newpoints := newpoints + 1;
899 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
902 havefirstpoint := false;
906 IF NOT havefirstpoint THEN
907 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
908 IF startnumber IS NOT NULL AND startnumber > 0 THEN
909 havefirstpoint := true;
910 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
911 prevnode := nextnode;
913 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
919 --RAISE WARNING 'interpolation points % ',newpoints;
926 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
932 country_code VARCHAR(2);
933 default_language VARCHAR(10);
937 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
940 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
941 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
945 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
946 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
947 RAISE WARNING 'invalid geometry %',NEW.osm_id;
951 IF NEW.osm_type = 'R' THEN
952 -- invalid multipolygons can crash postgis, don't even bother to try!
955 NEW.geometry := ST_buffer(NEW.geometry,0);
956 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
957 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
962 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
964 NEW.place_id := nextval('seq_place');
965 NEW.indexed_status := 1; --STATUS_NEW
967 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
969 NEW.partition := get_partition(NEW.calculated_country_code);
970 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
972 -- copy 'name' to or from the default language (if there is a default language)
973 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
974 default_language := get_country_language_code(NEW.calculated_country_code);
975 IF default_language IS NOT NULL THEN
976 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
977 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
978 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
979 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
984 IF NEW.admin_level > 15 THEN
985 NEW.admin_level := 15;
988 IF NEW.housenumber IS NOT NULL THEN
989 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
992 IF NEW.osm_type = 'X' THEN
993 -- E'X'ternal records should already be in the right format so do nothing
995 NEW.rank_search := 30;
996 NEW.rank_address := NEW.rank_search;
998 -- By doing in postgres we have the country available to us - currently only used for postcode
999 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
1001 IF NEW.postcode IS NULL THEN
1002 -- most likely just a part of a multipolygon postcode boundary, throw it away
1006 NEW.name := hstore('ref', NEW.postcode);
1008 IF NEW.calculated_country_code = 'gb' THEN
1010 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1011 NEW.rank_search := 25;
1012 NEW.rank_address := 5;
1013 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1014 NEW.rank_search := 23;
1015 NEW.rank_address := 5;
1016 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1017 NEW.rank_search := 21;
1018 NEW.rank_address := 5;
1021 ELSEIF NEW.calculated_country_code = 'sg' THEN
1023 IF NEW.postcode ~ '^([0-9]{6})$' THEN
1024 NEW.rank_search := 25;
1025 NEW.rank_address := 11;
1028 ELSEIF NEW.calculated_country_code = 'de' THEN
1030 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1031 NEW.rank_search := 21;
1032 NEW.rank_address := 11;
1036 -- Guess at the postcode format and coverage (!)
1037 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1038 NEW.rank_search := 21;
1039 NEW.rank_address := 11;
1041 -- Does it look splitable into and area and local code?
1042 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1044 IF postcode IS NOT NULL THEN
1045 NEW.rank_search := 25;
1046 NEW.rank_address := 11;
1047 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1048 NEW.rank_search := 21;
1049 NEW.rank_address := 11;
1054 ELSEIF NEW.class = 'place' THEN
1055 IF NEW.type in ('continent') THEN
1056 NEW.rank_search := 2;
1057 NEW.rank_address := NEW.rank_search;
1058 NEW.calculated_country_code := NULL;
1059 ELSEIF NEW.type in ('sea') THEN
1060 NEW.rank_search := 2;
1061 NEW.rank_address := 0;
1062 NEW.calculated_country_code := NULL;
1063 ELSEIF NEW.type in ('country') THEN
1064 NEW.rank_search := 4;
1065 NEW.rank_address := NEW.rank_search;
1066 ELSEIF NEW.type in ('state') THEN
1067 NEW.rank_search := 8;
1068 NEW.rank_address := NEW.rank_search;
1069 ELSEIF NEW.type in ('region') THEN
1070 NEW.rank_search := 18; -- dropped from previous value of 10
1071 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1072 ELSEIF NEW.type in ('county') THEN
1073 NEW.rank_search := 12;
1074 NEW.rank_address := NEW.rank_search;
1075 ELSEIF NEW.type in ('city') THEN
1076 NEW.rank_search := 16;
1077 NEW.rank_address := NEW.rank_search;
1078 ELSEIF NEW.type in ('island') THEN
1079 NEW.rank_search := 17;
1080 NEW.rank_address := 0;
1081 ELSEIF NEW.type in ('town') THEN
1082 NEW.rank_search := 18;
1083 NEW.rank_address := 16;
1084 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1085 NEW.rank_search := 19;
1086 NEW.rank_address := 16;
1087 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1088 NEW.rank_search := 20;
1089 NEW.rank_address := NEW.rank_search;
1090 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1091 NEW.rank_search := 20;
1092 NEW.rank_address := 0;
1093 -- Irish townlands, tagged as place=locality and locality=townland
1094 IF (NEW.extratags -> 'locality') = 'townland' THEN
1095 NEW.rank_address := 20;
1097 ELSEIF NEW.type in ('neighbourhood') THEN
1098 NEW.rank_search := 22;
1099 NEW.rank_address := 22;
1100 ELSEIF NEW.type in ('house','building') THEN
1101 NEW.rank_search := 30;
1102 NEW.rank_address := NEW.rank_search;
1103 ELSEIF NEW.type in ('houses') THEN
1104 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1105 -- insert new point into place for each derived building
1106 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1107 NEW.rank_search := 28;
1108 NEW.rank_address := 0;
1111 ELSEIF NEW.class = 'boundary' THEN
1112 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1113 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1116 NEW.rank_search := NEW.admin_level * 2;
1117 IF NEW.type = 'administrative' THEN
1118 NEW.rank_address := NEW.rank_search;
1120 NEW.rank_address := 0;
1122 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1123 NEW.rank_search := 22;
1124 NEW.rank_address := NEW.rank_search;
1125 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1126 NEW.rank_search := 18;
1127 NEW.rank_address := 0;
1128 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1129 NEW.rank_search := 4;
1130 NEW.rank_address := NEW.rank_search;
1131 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1133 -- any feature more than 5 square miles is probably worth indexing
1134 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1135 NEW.rank_search := 22;
1136 NEW.rank_address := NEW.rank_search;
1137 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1138 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1139 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1141 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1143 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1145 ELSEIF NEW.class = 'waterway' THEN
1146 IF NEW.osm_type = 'R' THEN
1147 NEW.rank_search := 16;
1149 NEW.rank_search := 17;
1151 NEW.rank_address := 0;
1152 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
1153 NEW.rank_search := 27;
1154 NEW.rank_address := NEW.rank_search;
1155 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1156 NEW.rank_search := 26;
1157 NEW.rank_address := NEW.rank_search;
1158 ELSEIF NEW.class = 'mountain_pass' THEN
1159 NEW.rank_search := 20;
1160 NEW.rank_address := 0;
1165 IF NEW.rank_search > 30 THEN
1166 NEW.rank_search := 30;
1169 IF NEW.rank_address > 30 THEN
1170 NEW.rank_address := 30;
1173 IF (NEW.extratags -> 'capital') = 'yes' THEN
1174 NEW.rank_search := NEW.rank_search - 1;
1177 -- a country code make no sense below rank 4 (country)
1178 IF NEW.rank_search < 4 THEN
1179 NEW.calculated_country_code := NULL;
1182 -- Block import below rank 22
1183 -- IF NEW.rank_search > 22 THEN
1187 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1189 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1191 IF NEW.rank_address > 0 THEN
1192 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1193 -- Performance: We just can't handle re-indexing for country level changes
1194 IF st_area(NEW.geometry) < 1 THEN
1195 -- mark items within the geometry for re-indexing
1196 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1198 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1199 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1200 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
1201 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1202 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
1205 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1207 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1208 IF NEW.type='postcode' THEN
1210 ELSEIF NEW.rank_search < 16 THEN
1212 ELSEIF NEW.rank_search < 18 THEN
1214 ELSEIF NEW.rank_search < 20 THEN
1216 ELSEIF NEW.rank_search = 21 THEN
1218 ELSEIF NEW.rank_search < 24 THEN
1220 ELSEIF NEW.rank_search < 26 THEN
1221 diameter := 0.002; -- 100 to 200 meters
1222 ELSEIF NEW.rank_search < 28 THEN
1223 diameter := 0.001; -- 50 to 100 meters
1225 IF diameter > 0 THEN
1226 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1227 IF NEW.rank_search >= 26 THEN
1228 -- roads may cause reparenting for >27 rank places
1229 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1230 ELSEIF NEW.rank_search >= 16 THEN
1231 -- up to rank 16, street-less addresses may need reparenting
1232 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
1234 -- for all other places the search terms may change as well
1235 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);
1241 -- add to tables for special search
1242 -- Note: won't work on initial import because the classtype tables
1243 -- do not yet exist. It won't hurt either.
1244 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1245 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1247 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1248 USING NEW.place_id, ST_Centroid(NEW.geometry);
1252 -- IF NEW.rank_search < 26 THEN
1253 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1262 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1267 place_centroid GEOMETRY;
1269 search_maxdistance FLOAT[];
1270 search_mindistance FLOAT[];
1271 address_havelevel BOOLEAN[];
1272 -- search_scores wordscore[];
1273 -- search_scores_pos INTEGER;
1280 relation_members TEXT[];
1282 linkedplacex RECORD;
1283 search_diameter FLOAT;
1284 search_prevdiameter FLOAT;
1285 search_maxrank INTEGER;
1286 address_maxrank INTEGER;
1287 address_street_word_id INTEGER;
1288 address_street_word_ids INTEGER[];
1289 parent_place_id_rank BIGINT;
1294 location_rank_search INTEGER;
1295 location_distance FLOAT;
1296 location_parent GEOMETRY;
1297 location_isaddress BOOLEAN;
1301 default_language TEXT;
1302 name_vector INTEGER[];
1303 nameaddress_vector INTEGER[];
1305 linked_node_id BIGINT;
1311 IF OLD.indexed_status = 100 THEN
1312 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1313 delete from placex where place_id = OLD.place_id;
1317 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1321 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1323 --RAISE WARNING '%',NEW.place_id;
1324 --RAISE WARNING '%', NEW;
1326 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1327 -- Silently do nothing
1331 -- TODO: this test is now redundant?
1332 IF OLD.indexed_status != 0 THEN
1334 NEW.indexed_date = now();
1336 result := deleteSearchName(NEW.partition, NEW.place_id);
1337 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1338 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1339 result := deleteRoad(NEW.partition, NEW.place_id);
1340 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1341 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1343 IF NEW.linked_place_id is not null THEN
1347 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1348 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1352 -- Speed up searches - just use the centroid of the feature
1353 -- cheaper but less acurate
1354 place_centroid := ST_PointOnSurface(NEW.geometry);
1355 NEW.centroid := null;
1357 -- reclaculate country and partition
1358 IF NEW.rank_search = 4 THEN
1359 -- for countries, believe the mapped country code,
1360 -- so that we remain in the right partition if the boundaries
1362 NEW.partition := get_partition(lower(NEW.country_code));
1363 IF NEW.partition = 0 THEN
1364 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1365 NEW.partition := get_partition(NEW.calculated_country_code);
1367 NEW.calculated_country_code := lower(NEW.country_code);
1370 IF NEW.rank_search > 4 THEN
1371 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1372 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1374 NEW.calculated_country_code := NULL;
1376 NEW.partition := get_partition(NEW.calculated_country_code);
1378 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1380 -- waterway ways are linked when they are part of a relation and have the same class/type
1381 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1382 FOR relation IN select * from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1384 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1385 IF relation.members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation.members[i],1,1) = 'w' THEN
1386 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.parts[i];
1387 FOR location IN SELECT * FROM placex
1388 WHERE osm_type = 'W' and osm_id = substring(relation.members[i],2,200)::bigint
1389 and class = NEW.class and type = NEW.type
1390 and ( relation.members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1392 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = location.place_id;
1399 -- Adding ourselves to the list simplifies address calculations later
1400 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1402 -- What level are we searching from
1403 search_maxrank := NEW.rank_search;
1405 -- Thought this wasn't needed but when we add new languages to the country_name table
1406 -- we need to update the existing names
1407 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1408 default_language := get_country_language_code(NEW.calculated_country_code);
1409 IF default_language IS NOT NULL THEN
1410 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1411 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1412 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1413 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1418 -- Initialise the name vector using our name
1419 name_vector := make_keywords(NEW.name);
1420 nameaddress_vector := '{}'::int[];
1422 -- some tag combinations add a special id for search
1423 tagpairid := get_tagpair(NEW.class,NEW.type);
1424 IF tagpairid IS NOT NULL THEN
1425 name_vector := name_vector + tagpairid;
1429 address_havelevel[i] := false;
1432 NEW.importance := null;
1433 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1434 IF NEW.importance IS NULL THEN
1435 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;
1438 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1440 -- For low level elements we inherit from our parent road
1441 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1443 --RAISE WARNING 'finding street for %', NEW;
1445 -- We won't get a better centroid, besides these places are too small to care
1446 NEW.centroid := place_centroid;
1448 NEW.parent_place_id := null;
1450 -- to do that we have to find our parent road
1451 -- Copy data from linked items (points on ways, addr:street links, relations)
1452 -- Note that addr:street links can only be indexed once the street itself is indexed
1453 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1455 -- if there is no address information, see if we can get it from a surrounding building
1456 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1457 FOR location IN select * from placex where ST_Covers(geometry, place_centroid) and rank_search > 28 and (housenumber is not null or street is not null or addr_place is not null) AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1459 NEW.housenumber := location.housenumber;
1460 NEW.street := location.street;
1461 NEW.addr_place := location.addr_place;
1465 -- Is this node part of a relation?
1466 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1468 -- At the moment we only process one type of relation - associatedStreet
1469 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1470 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1471 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1472 --RAISE WARNING 'node in relation %',relation;
1473 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1474 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1480 --RAISE WARNING 'x1';
1481 -- Is this node part of a way?
1482 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1483 --RAISE WARNING '%', way;
1484 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1486 --RAISE WARNING '%', location;
1487 -- Way IS a road then we are on it - that must be our road
1488 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1489 --RAISE WARNING 'node in way that is a street %',location;
1490 NEW.parent_place_id := location.place_id;
1493 -- Is the WAY part of a relation
1494 IF NEW.parent_place_id IS NULL THEN
1495 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1497 -- At the moment we only process one type of relation - associatedStreet
1498 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1499 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1500 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1501 --RAISE WARNING 'node in way that is in a relation %',relation;
1502 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1503 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1510 -- If the way contains an explicit name of a street copy it
1511 -- Slightly less strict then above because data is copied from any object.
1512 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1513 --RAISE WARNING 'node in way that has a streetname %',location;
1514 NEW.street := location.street;
1515 NEW.addr_place := location.addr_place;
1518 -- If this way is a street interpolation line then it is probably as good as we are going to get
1519 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND NEW.addr_place IS NULL AND location.class = 'place' and location.type='houses' THEN
1520 -- Try and find a way that is close roughly parellel to this line
1521 FOR relation IN SELECT place_id FROM placex
1522 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1523 and st_geometrytype(location.geometry) in ('ST_LineString')
1524 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1525 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1526 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1528 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1529 NEW.parent_place_id := relation.place_id;
1538 --RAISE WARNING 'x2';
1540 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1541 -- Is this way part of a relation?
1542 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1544 -- At the moment we only process one type of relation - associatedStreet
1545 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1546 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1547 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1548 --RAISE WARNING 'way that is in a relation %',relation;
1549 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1550 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1557 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1559 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1560 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1561 IF address_street_word_ids IS NOT NULL THEN
1562 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1563 NEW.parent_place_id := location.place_id;
1568 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1569 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1570 IF address_street_word_ids IS NOT NULL THEN
1571 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1572 NEW.parent_place_id := location.place_id;
1577 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1578 -- Still nothing, just use the nearest road
1579 IF NEW.parent_place_id IS NULL THEN
1580 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1581 NEW.parent_place_id := location.place_id;
1586 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1588 -- If we didn't find any road fallback to standard method
1589 IF NEW.parent_place_id IS NOT NULL THEN
1591 -- Add the street to the address as zero distance to force to front of list
1592 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1593 address_havelevel[26] := true;
1595 -- Import address details from parent, reclculating distance in process
1596 -- 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
1597 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1598 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1600 -- Get the details of the parent road
1601 select * from search_name where place_id = NEW.parent_place_id INTO location;
1602 NEW.calculated_country_code := location.country_code;
1604 --RAISE WARNING '%', NEW.name;
1605 -- If there is no name it isn't searchable, don't bother to create a search record
1606 IF NEW.name is NULL THEN
1610 -- Merge address from parent
1611 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1612 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1614 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1615 -- Just be happy with inheriting from parent road only
1617 IF NEW.rank_search <= 25 THEN
1618 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1621 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1628 -- RAISE WARNING ' INDEXING Started:';
1629 -- RAISE WARNING ' INDEXING: %',NEW;
1631 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1633 -- see if we have any special relation members
1634 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1636 -- RAISE WARNING 'get_osm_rel_members, label';
1637 IF relation_members IS NOT NULL THEN
1638 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1640 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1641 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1643 -- If we don't already have one use this as the centre point of the geometry
1644 IF NEW.centroid IS NULL THEN
1645 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1648 -- merge in the label name, re-init word vector
1649 IF NOT linkedPlacex.name IS NULL THEN
1650 NEW.name := linkedPlacex.name || NEW.name;
1651 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1654 -- merge in extra tags
1655 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1657 -- mark the linked place (excludes from search results)
1658 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1660 -- keep a note of the node id in case we need it for wikipedia in a bit
1661 linked_node_id := linkedPlacex.osm_id;
1666 IF NEW.centroid IS NULL THEN
1668 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1670 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1671 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1673 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1674 -- But that can be fixed by explicitly setting the label in the data
1675 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1676 AND NEW.rank_address = linkedPlacex.rank_address THEN
1678 -- If we don't already have one use this as the centre point of the geometry
1679 IF NEW.centroid IS NULL THEN
1680 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1683 -- merge in the name, re-init word vector
1684 IF NOT linkedPlacex.name IS NULL THEN
1685 NEW.name := linkedPlacex.name || NEW.name;
1686 name_vector := make_keywords(NEW.name);
1689 -- merge in extra tags
1690 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1692 -- mark the linked place (excludes from search results)
1693 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1695 -- keep a note of the node id in case we need it for wikipedia in a bit
1696 linked_node_id := linkedPlacex.osm_id;
1708 -- Name searches can be done for ways as well as relations
1709 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1711 -- not found one yet? how about doing a name search
1712 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1714 FOR linkedPlacex IN select placex.* from placex WHERE
1715 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1716 AND placex.rank_address = NEW.rank_address
1717 AND placex.place_id != NEW.place_id
1718 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1719 AND st_covers(NEW.geometry, placex.geometry)
1722 -- If we don't already have one use this as the centre point of the geometry
1723 IF NEW.centroid IS NULL THEN
1724 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1727 -- merge in the name, re-init word vector
1728 NEW.name := linkedPlacex.name || NEW.name;
1729 name_vector := make_keywords(NEW.name);
1731 -- merge in extra tags
1732 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1734 -- mark the linked place (excludes from search results)
1735 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1737 -- keep a note of the node id in case we need it for wikipedia in a bit
1738 linked_node_id := linkedPlacex.osm_id;
1742 IF NEW.centroid IS NOT NULL THEN
1743 place_centroid := NEW.centroid;
1744 -- Place might have had only a name tag before but has now received translations
1745 -- from the linked place. Make sure a name tag for the default language exists in
1747 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1748 default_language := get_country_language_code(NEW.calculated_country_code);
1749 IF default_language IS NOT NULL THEN
1750 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1751 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1752 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1753 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1759 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1760 IF NEW.importance is null THEN
1761 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1763 -- Still null? how about looking it up by the node id
1764 IF NEW.importance IS NULL THEN
1765 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;
1770 -- make sure all names are in the word table
1771 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1772 perform create_country(NEW.name, lower(NEW.country_code));
1775 NEW.parent_place_id = 0;
1776 parent_place_id_rank = 0;
1778 -- convert isin to array of tokenids
1779 isin_tokens := '{}'::int[];
1780 IF NEW.isin IS NOT NULL THEN
1781 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1782 IF array_upper(isin, 1) IS NOT NULL THEN
1783 FOR i IN 1..array_upper(isin, 1) LOOP
1784 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1785 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1786 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1787 isin_tokens := isin_tokens || address_street_word_id;
1790 -- merge word into address vector
1791 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1792 IF address_street_word_id IS NOT NULL THEN
1793 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1798 IF NEW.postcode IS NOT NULL THEN
1799 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1800 IF array_upper(isin, 1) IS NOT NULL THEN
1801 FOR i IN 1..array_upper(isin, 1) LOOP
1802 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1803 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1804 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1805 isin_tokens := isin_tokens || address_street_word_id;
1808 -- merge into address vector
1809 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1810 IF address_street_word_id IS NOT NULL THEN
1811 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1817 -- for the USA we have an additional address table. Merge in zip codes from there too
1818 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1819 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1820 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1821 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1822 isin_tokens := isin_tokens || address_street_word_id;
1824 -- also merge in the single word version
1825 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1826 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1830 -- RAISE WARNING 'ISIN: %', isin_tokens;
1832 -- Process area matches
1833 location_rank_search := 0;
1834 location_distance := 0;
1835 location_parent := NULL;
1836 -- added ourself as address already
1837 address_havelevel[NEW.rank_address] := true;
1838 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1839 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1841 --RAISE WARNING ' AREA: %',location;
1843 IF location.rank_address != location_rank_search THEN
1844 location_rank_search := location.rank_address;
1845 location_distance := location.distance * 1.5;
1848 IF location.distance < location_distance OR NOT location.isguess THEN
1850 location_isaddress := NOT address_havelevel[location.rank_address];
1851 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1852 location_isaddress := ST_Contains(location_parent,location.centroid);
1855 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1856 -- Add it to the list of search terms
1857 IF location.rank_search > 4 THEN
1858 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1860 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1862 IF location_isaddress THEN
1864 address_havelevel[location.rank_address] := true;
1865 IF NOT location.isguess THEN
1866 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1869 IF location.rank_address > parent_place_id_rank THEN
1870 NEW.parent_place_id = location.place_id;
1871 parent_place_id_rank = location.rank_address;
1876 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1882 -- try using the isin value to find parent places
1883 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1884 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1885 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1886 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1888 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1890 --RAISE WARNING ' ISIN: %',location;
1892 IF location.rank_search > 4 THEN
1893 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1894 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1895 address_havelevel[location.rank_address] := true;
1897 IF location.rank_address > parent_place_id_rank THEN
1898 NEW.parent_place_id = location.place_id;
1899 parent_place_id_rank = location.rank_address;
1909 -- for long ways we should add search terms for the entire length
1910 IF st_length(NEW.geometry) > 0.05 THEN
1912 location_rank_search := 0;
1913 location_distance := 0;
1915 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1917 IF location.rank_address != location_rank_search THEN
1918 location_rank_search := location.rank_address;
1919 location_distance := location.distance * 1.5;
1922 IF location.rank_search > 4 AND location.distance < location_distance THEN
1924 -- Add it to the list of search terms
1925 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1926 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1934 -- if we have a name add this to the name search table
1935 IF NEW.name IS NOT NULL THEN
1937 IF NEW.rank_search <= 25 THEN
1938 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1941 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1942 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1945 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1949 -- If we've not managed to pick up a better one - default centroid
1950 IF NEW.centroid IS NULL THEN
1951 NEW.centroid := place_centroid;
1961 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1967 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1969 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1970 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1971 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1972 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1974 IF OLD.rank_address < 30 THEN
1976 -- mark everything linked to this place for re-indexing
1977 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1978 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1979 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1981 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1982 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1984 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1985 b := deleteRoad(OLD.partition, OLD.place_id);
1987 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1988 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1989 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1993 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1995 IF OLD.rank_address < 26 THEN
1996 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1999 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2001 IF OLD.name is not null THEN
2002 b := deleteSearchName(OLD.partition, OLD.place_id);
2005 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2007 DELETE FROM place_addressline where place_id = OLD.place_id;
2009 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2011 -- remove from tables for special search
2012 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2013 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2015 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2018 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2026 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2032 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2034 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2035 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2036 SELECT bool_or(not (rank_address = 0 or rank_address > 26)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
2038 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2044 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;
2052 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2057 existingplacex RECORD;
2058 existinggeometry GEOMETRY;
2059 existingplace_id BIGINT;
2064 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2065 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2067 IF FALSE and NEW.osm_type = 'R' THEN
2068 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;
2069 --DEBUG: RAISE WARNING '%', existingplacex;
2072 -- Just block these - lots and pointless
2073 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2074 -- if the name tag was removed, older versions might still be lurking in the place table
2075 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2079 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
2080 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2081 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2082 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2086 -- Patch in additional country names
2087 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2088 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2091 -- Have we already done this place?
2092 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;
2094 -- Get the existing place_id
2095 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;
2097 -- Handle a place changing type by removing the old data
2098 -- My generated 'place' types are causing havok because they overlap with real keys
2099 -- TODO: move them to their own special purpose key/class to avoid collisions
2100 IF existing.osm_type IS NULL THEN
2101 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2104 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2105 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2108 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2109 AND st_area(existing.geometry) > 0.02
2110 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2111 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2113 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2114 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2118 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2119 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2121 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2122 IF existingplacex.osm_type IS NULL OR
2123 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2126 IF existingplacex.osm_type IS NOT NULL THEN
2127 -- sanity check: ignore admin_level changes on places with too many active children
2128 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2129 --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i;
2130 --LIMIT INDEXING: IF i > 100000 THEN
2131 --LIMIT INDEXING: RETURN null;
2132 --LIMIT INDEXING: END IF;
2135 IF existing.osm_type IS NOT NULL THEN
2136 -- pathological case caused by the triggerless copy into place during initial import
2137 -- force delete even for large areas, it will be reinserted later
2138 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2139 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2142 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2143 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2144 street, addr_place, isin, postcode, country_code, extratags, geometry)
2145 values (NEW.osm_type
2161 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2166 -- Various ways to do the update
2168 -- Debug, what's changed?
2170 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2171 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2173 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2174 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2176 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2177 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2179 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2180 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2182 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2183 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2185 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2186 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2188 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2189 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2193 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2194 IF existing.geometry::text != NEW.geometry::text
2195 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2196 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2199 -- Get the version of the geometry actually used (in placex table)
2200 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;
2202 -- Performance limit
2203 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2205 -- 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
2206 update placex set indexed_status = 2 where indexed_status = 0 and
2207 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2208 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2209 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2211 update placex set indexed_status = 2 where indexed_status = 0 and
2212 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2213 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2214 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2220 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2221 IF FALSE AND existingplacex.rank_search < 26
2222 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2223 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2224 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2225 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2226 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2227 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2228 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2231 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2233 IF st_area(NEW.geometry) < 0.5 THEN
2234 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2235 and placex.place_id = place_addressline.place_id and indexed_status = 0
2236 and (rank_search < 28 or name is not null);
2243 -- Anything else has changed - reindex the lot
2244 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2245 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2246 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2247 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2248 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2249 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2250 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2252 -- performance, can't take the load of re-indexing a whole country / huge area
2253 IF st_area(NEW.geometry) < 0.5 THEN
2254 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2255 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2262 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2263 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2264 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2265 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2266 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2267 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2268 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2269 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2270 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2271 OR existing.geometry::text != NEW.geometry::text
2276 housenumber = NEW.housenumber,
2277 street = NEW.street,
2278 addr_place = NEW.addr_place,
2280 postcode = NEW.postcode,
2281 country_code = NEW.country_code,
2282 extratags = NEW.extratags,
2283 admin_level = NEW.admin_level,
2284 geometry = NEW.geometry
2285 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2287 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2288 IF NEW.postcode IS NULL THEN
2289 -- postcode was deleted, no longer retain in placex
2290 DELETE FROM placex where place_id = existingplacex.place_id;
2294 NEW.name := hstore('ref', NEW.postcode);
2299 housenumber = NEW.housenumber,
2300 street = NEW.street,
2301 addr_place = NEW.addr_place,
2303 postcode = NEW.postcode,
2304 country_code = NEW.country_code,
2305 parent_place_id = null,
2306 extratags = NEW.extratags,
2307 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2309 geometry = NEW.geometry
2310 where place_id = existingplacex.place_id;
2314 -- Abort the add (we modified the existing place instead)
2318 $$ LANGUAGE plpgsql;
2320 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2327 IF name is null THEN
2331 search := languagepref;
2333 FOR j IN 1..array_upper(search, 1) LOOP
2334 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2335 return trim(name->search[j]);
2339 -- anything will do as a fallback - just take the first name type thing there is
2340 search := avals(name);
2344 LANGUAGE plpgsql IMMUTABLE;
2346 --CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2349 -- searchnodes INTEGER[];
2354 -- searchnodes := '{}';
2355 -- FOR j IN 1..array_upper(way_ids, 1) LOOP
2357 -- select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2359 -- IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2360 -- searchnodes := searchnodes || location.nodes;
2365 -- RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2368 --LANGUAGE plpgsql IMMUTABLE;
2370 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2381 search := ARRAY['ref'];
2384 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2387 select rank_address,name,distance,length(name::text) as namelength
2388 from place_addressline join placex on (address_place_id = placex.place_id)
2389 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2390 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2392 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2393 FOR j IN 1..array_upper(search, 1) LOOP
2394 FOR k IN 1..array_upper(location.name, 1) LOOP
2395 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
2396 result[(100 - location.rank_address)] := trim(location.name[k].value);
2397 found := location.rank_address;
2404 RETURN array_to_string(result,', ');
2409 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2421 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2422 currresult := trim(get_name_by_language(location.name, languagepref));
2423 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2424 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2425 prevresult := currresult;
2429 RETURN array_to_string(result,', ');
2434 DROP TYPE IF EXISTS addressline CASCADE;
2435 create type addressline as (
2442 admin_level INTEGER,
2445 rank_address INTEGER,
2449 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2452 for_place_id BIGINT;
2457 countrylocation RECORD;
2458 searchcountrycode varchar(2);
2459 searchhousenumber TEXT;
2460 searchhousename HSTORE;
2461 searchrankaddress INTEGER;
2462 searchpostcode TEXT;
2469 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2470 WHERE place_id = in_place_id
2471 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2473 IF for_place_id IS NULL THEN
2474 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2475 WHERE place_id = in_place_id
2476 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2479 IF for_place_id IS NULL THEN
2480 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2481 WHERE place_id = in_place_id and rank_address = 30
2482 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2485 IF for_place_id IS NULL THEN
2486 for_place_id := in_place_id;
2487 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2488 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2491 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2494 hadcountry := false;
2496 select placex.place_id, osm_type, osm_id,
2497 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2498 class, type, admin_level, true as fromarea, true as isaddress,
2499 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2500 0 as distance, calculated_country_code, postcode
2502 where place_id = for_place_id
2504 --RAISE WARNING '%',location;
2505 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2506 searchcountrycode := location.calculated_country_code;
2508 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2509 location.isaddress := FALSE;
2511 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2512 searchpostcode := location.postcode;
2514 IF location.rank_address = 4 AND location.isaddress THEN
2517 IF location.rank_address < 4 AND NOT hadcountry THEN
2518 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2519 IF countryname IS NOT NULL THEN
2520 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2521 RETURN NEXT countrylocation;
2524 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2525 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2526 location.distance)::addressline;
2527 RETURN NEXT countrylocation;
2528 found := location.rank_address;
2532 select placex.place_id, osm_type, osm_id,
2533 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2534 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2535 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2536 admin_level, fromarea, isaddress,
2537 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,
2538 distance,calculated_country_code,postcode
2539 from place_addressline join placex on (address_place_id = placex.place_id)
2540 where place_addressline.place_id = for_place_id
2541 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2542 and address_place_id != for_place_id
2543 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2544 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2546 --RAISE WARNING '%',location;
2547 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2548 searchcountrycode := location.calculated_country_code;
2550 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2551 location.isaddress := FALSE;
2553 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2554 searchpostcode := location.postcode;
2556 IF location.rank_address = 4 AND location.isaddress THEN
2559 IF location.rank_address < 4 AND NOT hadcountry THEN
2560 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2561 IF countryname IS NOT NULL THEN
2562 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2563 RETURN NEXT countrylocation;
2566 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2567 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2568 location.distance)::addressline;
2569 RETURN NEXT countrylocation;
2570 found := location.rank_address;
2574 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2575 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2576 IF countryname IS NOT NULL THEN
2577 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2578 RETURN NEXT location;
2582 IF searchcountrycode IS NOT NULL THEN
2583 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2584 RETURN NEXT location;
2587 IF searchhousename IS NOT NULL THEN
2588 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2589 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2590 RETURN NEXT location;
2593 IF searchhousenumber IS NOT NULL THEN
2594 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2595 RETURN NEXT location;
2598 IF searchpostcode IS NOT NULL THEN
2599 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2600 RETURN NEXT location;
2608 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2611 result place_boundingbox;
2612 numfeatures integer;
2614 select * from place_boundingbox into result where place_id = search_place_id;
2615 IF result.place_id IS NULL THEN
2616 -- remove isaddress = true because if there is a matching polygon it always wins
2617 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2618 insert into place_boundingbox select place_id,
2619 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2620 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2621 numfeatures, ST_Area(geometry),
2622 geometry as area from location_area where place_id = search_place_id;
2623 select * from place_boundingbox into result where place_id = search_place_id;
2625 IF result.place_id IS NULL THEN
2627 insert into place_boundingbox select address_place_id,
2628 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2629 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2630 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2631 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2632 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)
2633 where address_place_id = search_place_id
2634 -- and (isaddress = true OR place_id = search_place_id)
2635 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2636 group by address_place_id limit 1;
2637 select * from place_boundingbox into result where place_id = search_place_id;
2644 -- don't do the operation if it would be slow
2645 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2648 result place_boundingbox;
2649 numfeatures integer;
2652 select * from place_boundingbox into result where place_id = search_place_id;
2653 IF result IS NULL AND rank > 14 THEN
2654 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2655 insert into place_boundingbox select place_id,
2656 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2657 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2658 numfeatures, ST_Area(geometry),
2659 geometry as area from location_area where place_id = search_place_id;
2660 select * from place_boundingbox into result where place_id = search_place_id;
2662 IF result IS NULL THEN
2663 select rank_search from placex where place_id = search_place_id into rank;
2666 insert into place_boundingbox select address_place_id,
2667 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2668 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2669 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2670 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2671 from place_addressline join placex using (place_id)
2672 where address_place_id = search_place_id
2673 and (isaddress = true OR place_id = search_place_id)
2674 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2675 group by address_place_id limit 1;
2676 select * from place_boundingbox into result where place_id = search_place_id;
2684 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2687 result place_boundingbox;
2688 numfeatures integer;
2692 housenumber = place.housenumber,
2693 street = place.street,
2694 addr_place = place.addr_place,
2696 postcode = place.postcode,
2697 country_code = place.country_code,
2698 parent_place_id = null
2700 where placex.place_id = search_place_id
2701 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2702 and place.class = placex.class and place.type = placex.type;
2703 update placex set indexed_status = 2 where place_id = search_place_id;
2704 update placex set indexed_status = 0 where place_id = search_place_id;
2710 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2716 ELSEIF rank < 4 THEN
2718 ELSEIF rank < 8 THEN
2720 ELSEIF rank < 12 THEN
2722 ELSEIF rank < 16 THEN
2724 ELSEIF rank = 16 THEN
2726 ELSEIF rank = 17 THEN
2727 RETURN 'Town / Island';
2728 ELSEIF rank = 18 THEN
2729 RETURN 'Village / Hamlet';
2730 ELSEIF rank = 20 THEN
2732 ELSEIF rank = 21 THEN
2733 RETURN 'Postcode Area';
2734 ELSEIF rank = 22 THEN
2735 RETURN 'Croft / Farm / Locality / Islet';
2736 ELSEIF rank = 23 THEN
2737 RETURN 'Postcode Area';
2738 ELSEIF rank = 25 THEN
2739 RETURN 'Postcode Point';
2740 ELSEIF rank = 26 THEN
2741 RETURN 'Street / Major Landmark';
2742 ELSEIF rank = 27 THEN
2743 RETURN 'Minory Street / Path';
2744 ELSEIF rank = 28 THEN
2745 RETURN 'House / Building';
2747 RETURN 'Other: '||rank;
2754 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2760 ELSEIF rank < 2 THEN
2762 ELSEIF rank < 4 THEN
2764 ELSEIF rank = 5 THEN
2766 ELSEIF rank < 8 THEN
2768 ELSEIF rank < 12 THEN
2770 ELSEIF rank < 16 THEN
2772 ELSEIF rank = 16 THEN
2774 ELSEIF rank = 17 THEN
2775 RETURN 'Town / Village / Hamlet';
2776 ELSEIF rank = 20 THEN
2778 ELSEIF rank = 21 THEN
2779 RETURN 'Postcode Area';
2780 ELSEIF rank = 22 THEN
2781 RETURN 'Croft / Farm / Locality / Islet';
2782 ELSEIF rank = 23 THEN
2783 RETURN 'Postcode Area';
2784 ELSEIF rank = 25 THEN
2785 RETURN 'Postcode Point';
2786 ELSEIF rank = 26 THEN
2787 RETURN 'Street / Major Landmark';
2788 ELSEIF rank = 27 THEN
2789 RETURN 'Minory Street / Path';
2790 ELSEIF rank = 28 THEN
2791 RETURN 'House / Building';
2793 RETURN 'Other: '||rank;
2800 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2807 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2808 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2815 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2823 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2825 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2826 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2828 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2836 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2837 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2842 place_centroid GEOMETRY;
2843 out_partition INTEGER;
2844 out_parent_place_id BIGINT;
2846 address_street_word_id INTEGER;
2851 place_centroid := ST_Centroid(pointgeo);
2852 out_partition := get_partition(in_countrycode);
2853 out_parent_place_id := null;
2855 address_street_word_id := get_name_id(make_standard_name(in_street));
2856 IF address_street_word_id IS NOT NULL THEN
2857 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2858 out_parent_place_id := location.place_id;
2862 IF out_parent_place_id IS NULL THEN
2863 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2864 out_parent_place_id := location.place_id;
2868 out_postcode := in_postcode;
2869 IF out_postcode IS NULL THEN
2870 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2872 IF out_postcode IS NULL THEN
2873 out_postcode := getNearestPostcode(out_partition, place_centroid);
2877 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2878 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2879 newpoints := newpoints + 1;
2886 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2893 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2894 IF members[i+1] = member THEN
2895 result := result || members[i];
2904 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2910 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2911 IF members[i+1] = ANY(memberLabels) THEN
2912 RETURN NEXT members[i];
2921 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2922 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2924 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2925 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
2926 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2927 ), '') AS bytea), 'UTF8');
2929 LANGUAGE SQL IMMUTABLE STRICT;
2931 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2935 RETURN decode_url_part(p);
2937 WHEN others THEN return null;
2940 LANGUAGE plpgsql IMMUTABLE;
2942 DROP TYPE wikipedia_article_match CASCADE;
2943 create type wikipedia_article_match as (
2949 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2955 wiki_article_title TEXT;
2956 wiki_article_language TEXT;
2957 result wikipedia_article_match;
2959 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'];
2961 WHILE langs[i] IS NOT NULL LOOP
2962 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2963 IF wiki_article is not null THEN
2964 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2965 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2966 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2967 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2968 wiki_article := replace(wiki_article,' ','_');
2969 IF strpos(wiki_article, ':') IN (3,4) THEN
2970 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2971 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2973 wiki_article_title := trim(wiki_article);
2974 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;
2977 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2978 from wikipedia_article
2979 where language = wiki_article_language and
2980 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2982 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2983 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2984 where wikipedia_redirect.language = wiki_article_language and
2985 (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'\\',''))
2986 order by importance desc limit 1 INTO result;
2988 IF result.language is not null THEN
2999 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
3000 RETURNS SETOF GEOMETRY
3014 remainingdepth INTEGER;
3019 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
3021 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
3022 RETURN NEXT geometry;
3026 remainingdepth := maxdepth - 1;
3027 area := ST_AREA(geometry);
3028 IF remainingdepth < 1 OR area < maxarea THEN
3029 RETURN NEXT geometry;
3033 xmin := st_xmin(geometry);
3034 xmax := st_xmax(geometry);
3035 ymin := st_ymin(geometry);
3036 ymax := st_ymax(geometry);
3037 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
3039 -- if the geometry completely covers the box don't bother to slice any more
3040 IF ST_AREA(secbox) = area THEN
3041 RETURN NEXT geometry;
3045 xmid := (xmin+xmax)/2;
3046 ymid := (ymin+ymax)/2;
3049 FOR seg IN 1..4 LOOP
3052 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
3055 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
3058 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3061 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3064 IF st_intersects(geometry, secbox) THEN
3065 secgeo := st_intersection(geometry, secbox);
3066 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3067 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3068 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3070 RETURN NEXT geo.geom;
3082 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3083 RETURNS SETOF GEOMETRY
3088 -- 10000000000 is ~~ 1x1 degree
3089 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3090 RETURN NEXT geo.geom;
3098 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3102 osmtype character(1);
3106 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3107 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3108 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3109 -- force delete from place/placex by making it a very small geometry
3110 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;
3111 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3118 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3126 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
3127 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3128 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3129 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3130 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3131 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3132 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
3133 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3134 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
3140 ELSEIF rank < 18 THEN
3142 ELSEIF rank < 20 THEN
3144 ELSEIF rank = 21 THEN
3146 ELSEIF rank < 24 THEN
3148 ELSEIF rank < 26 THEN
3149 diameter := 0.002; -- 100 to 200 meters
3150 ELSEIF rank < 28 THEN
3151 diameter := 0.001; -- 50 to 100 meters
3153 IF diameter > 0 THEN
3155 -- roads may cause reparenting for >27 rank places
3156 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3157 ELSEIF rank >= 16 THEN
3158 -- up to rank 16, street-less addresses may need reparenting
3159 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
3161 -- for all other places the search terms may change as well
3162 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);