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 array_merge(a INTEGER[], b INTEGER[])
281 IF array_upper(a, 1) IS NULL THEN
284 IF array_upper(b, 1) IS NULL THEN
288 FOR i IN 1..array_upper(b, 1) LOOP
289 IF NOT (ARRAY[b[i]] <@ r) THEN
296 LANGUAGE plpgsql IMMUTABLE;
298 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
307 FOR item IN SELECT (each(src)).* LOOP
309 s := make_standard_name(item.value);
310 w := getorcreate_country(s, lookup_country_code);
312 words := regexp_split_to_array(item.value, E'[,;()]');
313 IF array_upper(words, 1) != 1 THEN
314 FOR j IN 1..array_upper(words, 1) LOOP
315 s := make_standard_name(words[j]);
317 w := getorcreate_country(s, lookup_country_code);
326 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
336 result := '{}'::INTEGER[];
338 FOR item IN SELECT (each(src)).* LOOP
340 s := make_standard_name(item.value);
342 w := getorcreate_name_id(s, item.value);
344 IF not(ARRAY[w] <@ result) THEN
345 result := result || w;
348 w := getorcreate_word_id(s);
350 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
351 result := result || w;
354 words := string_to_array(s, ' ');
355 IF array_upper(words, 1) IS NOT NULL THEN
356 FOR j IN 1..array_upper(words, 1) LOOP
357 IF (words[j] != '') THEN
358 w = getorcreate_word_id(words[j]);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
366 words := regexp_split_to_array(item.value, E'[,;()]');
367 IF array_upper(words, 1) != 1 THEN
368 FOR j IN 1..array_upper(words, 1) LOOP
369 s := make_standard_name(words[j]);
371 w := getorcreate_word_id(s);
372 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
373 result := result || w;
379 s := regexp_replace(item.value, '市$', '');
380 IF s != item.value THEN
381 s := make_standard_name(s);
383 w := getorcreate_name_id(s, item.value);
384 IF NOT (ARRAY[w] <@ result) THEN
385 result := result || w;
395 LANGUAGE plpgsql IMMUTABLE;
397 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
407 result := '{}'::INTEGER[];
409 s := make_standard_name(src);
410 w := getorcreate_name_id(s, src);
412 IF NOT (ARRAY[w] <@ result) THEN
413 result := result || w;
416 w := getorcreate_word_id(s);
418 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
419 result := result || w;
422 words := string_to_array(s, ' ');
423 IF array_upper(words, 1) IS NOT NULL THEN
424 FOR j IN 1..array_upper(words, 1) LOOP
425 IF (words[j] != '') THEN
426 w = getorcreate_word_id(words[j]);
427 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
428 result := result || w;
434 words := regexp_split_to_array(src, E'[,;()]');
435 IF array_upper(words, 1) != 1 THEN
436 FOR j IN 1..array_upper(words, 1) LOOP
437 s := make_standard_name(words[j]);
439 w := getorcreate_word_id(s);
440 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
441 result := result || w;
447 s := regexp_replace(src, '市$', '');
449 s := make_standard_name(s);
451 w := getorcreate_name_id(s, src);
452 IF NOT (ARRAY[w] <@ result) THEN
453 result := result || w;
461 LANGUAGE plpgsql IMMUTABLE;
463 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
470 IF (wordscores is null OR words is null) THEN
475 FOR idxword in 1 .. array_upper(words, 1) LOOP
476 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
477 IF wordscores[idxscores].word = words[idxword] THEN
478 result := result + wordscores[idxscores].score;
486 LANGUAGE plpgsql IMMUTABLE;
488 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
491 place_centre GEOMETRY;
494 place_centre := ST_PointOnSurface(place);
496 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
498 -- Try for a OSM polygon
499 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
501 RETURN nearcountry.country_code;
504 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
506 -- Try for OSM fallback data
507 -- The order is to deal with places like HongKong that are 'states' within another polygon
508 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
510 RETURN nearcountry.country_code;
513 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
515 -- Natural earth data
516 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
518 RETURN nearcountry.country_code;
521 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
524 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
526 RETURN nearcountry.country_code;
529 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
531 -- Natural earth data
532 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
534 RETURN nearcountry.country_code;
537 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
538 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
540 -- RETURN nearcountry.country_code;
543 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
545 -- Still not in a country - try nearest within ~12 miles of a country
546 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
547 -- order by st_distance(geometry, place) limit 1
549 -- RETURN nearcountry.country_code;
555 LANGUAGE plpgsql IMMUTABLE;
557 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
562 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
564 RETURN lower(nearcountry.country_default_language_code);
569 LANGUAGE plpgsql IMMUTABLE;
571 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
576 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
578 RETURN lower(nearcountry.country_default_language_codes);
583 LANGUAGE plpgsql IMMUTABLE;
585 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
590 FOR nearcountry IN select partition from country_name where country_code = in_country_code
592 RETURN nearcountry.partition;
597 LANGUAGE plpgsql IMMUTABLE;
599 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
603 DELETE FROM location_area where place_id = OLD_place_id;
604 -- TODO:location_area
610 CREATE OR REPLACE FUNCTION add_location(
612 country_code varchar(2),
616 rank_address INTEGER,
631 IF rank_search > 25 THEN
632 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
635 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
637 x := deleteLocationArea(partition, place_id, rank_search);
640 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
643 centroid := ST_Centroid(geometry);
645 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
646 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
649 ELSEIF rank_search < 26 THEN
652 IF rank_address = 0 THEN
654 ELSEIF rank_search <= 14 THEN
656 ELSEIF rank_search <= 15 THEN
658 ELSEIF rank_search <= 16 THEN
660 ELSEIF rank_search <= 17 THEN
662 ELSEIF rank_search <= 21 THEN
664 ELSEIF rank_search = 25 THEN
668 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
670 secgeo := ST_Buffer(geometry, diameter);
671 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
676 secgeo := ST_Buffer(geometry, 0.0002);
677 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
680 secgeo := ST_Buffer(geometry, 0.001);
681 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
690 CREATE OR REPLACE FUNCTION update_location(
693 place_country_code varchar(2),
696 rank_address INTEGER,
704 b := deleteLocationArea(partition, place_id, rank_search);
705 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
706 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
711 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
722 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
723 FOR childplace IN select * from search_name,place_addressline
724 where address_place_id = parent_place_id
725 and search_name.place_id = place_addressline.place_id
727 delete from search_name where place_id = childplace.place_id;
728 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
729 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
731 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
732 childplace.name_vector := childplace.name_vector || to_add;
734 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
735 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
736 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
744 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
747 newkeywords INTEGER[];
748 addedkeywords INTEGER[];
749 removedkeywords INTEGER[];
753 newkeywords := make_keywords(name);
754 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
755 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
756 where place_id = OLD_place_id into addedkeywords, removedkeywords;
758 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
760 IF #removedkeywords > 0 THEN
761 -- abort due to tokens removed
765 IF #addedkeywords > 0 THEN
766 -- short circuit - no changes
770 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
771 RETURN search_name_add_words(OLD_place_id, addedkeywords);
777 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
789 orginalstartnumber INTEGER;
790 originalnumberrange INTEGER;
793 search_place_id BIGINT;
796 havefirstpoint BOOLEAN;
800 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
802 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
803 select nodes from planet_osm_ways where id = wayid INTO waynodes;
804 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
805 IF array_upper(waynodes, 1) IS NOT NULL THEN
807 havefirstpoint := false;
809 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
811 -- If there is a place of a type other than place/house, use that because
812 -- it is guaranteed to be the original node. For place/house types use the
813 -- one with the smallest id because the original node was created first.
814 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
815 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;
816 IF search_place_id IS NULL THEN
817 -- if no such node exists, create a record of the right type
818 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and type = 'house' limit 1 INTO nextnode;
819 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
820 IF nextnode.geometry IS NULL THEN
821 -- we don't have any information about this point, most likely
822 -- because an excerpt was updated and the node never imported
823 -- because the interpolation is outside the region of the excerpt.
828 select * from placex where place_id = search_place_id INTO nextnode;
831 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
833 IF havefirstpoint THEN
835 -- add point to the line string
836 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
837 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
839 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
841 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
843 IF startnumber != endnumber THEN
845 linestr := linestr || ')';
846 --RAISE WARNING 'linestr %',linestr;
847 linegeo := ST_GeomFromText(linestr,4326);
848 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
849 IF (startnumber > endnumber) THEN
850 housenum := endnumber;
851 endnumber := startnumber;
852 startnumber := housenum;
853 linegeo := ST_Reverse(linegeo);
855 orginalstartnumber := startnumber;
856 originalnumberrange := endnumber - startnumber;
858 -- Too much broken data worldwide for this test to be worth using
859 -- IF originalnumberrange > 500 THEN
860 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
863 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
864 startnumber := startnumber + 1;
867 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
868 startnumber := startnumber + 2;
870 ELSE -- everything else assumed to be 'all'
871 startnumber := startnumber + 1;
875 endnumber := endnumber - 1;
876 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
877 FOR housenum IN startnumber..endnumber BY stepsize LOOP
878 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
879 -- ideally postcodes should move up to the way
880 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, addr_place, isin, postcode,
881 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
882 values ('N',prevnode.osm_id, 'place', 'house', prevnode.admin_level, housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
883 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_LineInterpolatePoint(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
884 newpoints := newpoints + 1;
885 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
888 havefirstpoint := false;
892 IF NOT havefirstpoint THEN
893 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
894 IF startnumber IS NOT NULL AND startnumber > 0 THEN
895 havefirstpoint := true;
896 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
897 prevnode := nextnode;
899 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
905 --RAISE WARNING 'interpolation points % ',newpoints;
912 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
918 country_code VARCHAR(2);
919 default_language VARCHAR(10);
923 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
926 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
927 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
931 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
932 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
933 RAISE WARNING 'invalid geometry %',NEW.osm_id;
937 IF NEW.osm_type = 'R' THEN
938 -- invalid multipolygons can crash postgis, don't even bother to try!
941 NEW.geometry := ST_buffer(NEW.geometry,0);
942 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
943 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
948 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
950 NEW.place_id := nextval('seq_place');
951 NEW.indexed_status := 1; --STATUS_NEW
953 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
955 NEW.partition := get_partition(NEW.calculated_country_code);
956 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
958 -- copy 'name' to or from the default language (if there is a default language)
959 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
960 default_language := get_country_language_code(NEW.calculated_country_code);
961 IF default_language IS NOT NULL THEN
962 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
963 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
964 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
965 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
970 IF NEW.admin_level > 15 THEN
971 NEW.admin_level := 15;
974 IF NEW.housenumber IS NOT NULL THEN
975 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
978 IF NEW.osm_type = 'X' THEN
979 -- E'X'ternal records should already be in the right format so do nothing
981 NEW.rank_search := 30;
982 NEW.rank_address := NEW.rank_search;
984 -- By doing in postgres we have the country available to us - currently only used for postcode
985 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
987 IF NEW.postcode IS NULL THEN
988 -- most likely just a part of a multipolygon postcode boundary, throw it away
992 NEW.name := hstore('ref', NEW.postcode);
994 IF NEW.calculated_country_code = 'gb' THEN
996 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
997 NEW.rank_search := 25;
998 NEW.rank_address := 5;
999 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1000 NEW.rank_search := 23;
1001 NEW.rank_address := 5;
1002 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1003 NEW.rank_search := 21;
1004 NEW.rank_address := 5;
1007 ELSEIF NEW.calculated_country_code = 'de' THEN
1009 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1010 NEW.rank_search := 21;
1011 NEW.rank_address := 11;
1015 -- Guess at the postcode format and coverage (!)
1016 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1017 NEW.rank_search := 21;
1018 NEW.rank_address := 11;
1020 -- Does it look splitable into and area and local code?
1021 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1023 IF postcode IS NOT NULL THEN
1024 NEW.rank_search := 25;
1025 NEW.rank_address := 11;
1026 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1027 NEW.rank_search := 21;
1028 NEW.rank_address := 11;
1033 ELSEIF NEW.class = 'place' THEN
1034 IF NEW.type in ('continent') THEN
1035 NEW.rank_search := 2;
1036 NEW.rank_address := NEW.rank_search;
1037 NEW.calculated_country_code := NULL;
1038 ELSEIF NEW.type in ('sea') THEN
1039 NEW.rank_search := 2;
1040 NEW.rank_address := 0;
1041 NEW.calculated_country_code := NULL;
1042 ELSEIF NEW.type in ('country') THEN
1043 NEW.rank_search := 4;
1044 NEW.rank_address := NEW.rank_search;
1045 ELSEIF NEW.type in ('state') THEN
1046 NEW.rank_search := 8;
1047 NEW.rank_address := NEW.rank_search;
1048 ELSEIF NEW.type in ('region') THEN
1049 NEW.rank_search := 18; -- dropped from previous value of 10
1050 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1051 ELSEIF NEW.type in ('county') THEN
1052 NEW.rank_search := 12;
1053 NEW.rank_address := NEW.rank_search;
1054 ELSEIF NEW.type in ('city') THEN
1055 NEW.rank_search := 16;
1056 NEW.rank_address := NEW.rank_search;
1057 ELSEIF NEW.type in ('island') THEN
1058 NEW.rank_search := 17;
1059 NEW.rank_address := 0;
1060 ELSEIF NEW.type in ('town') THEN
1061 NEW.rank_search := 18;
1062 NEW.rank_address := 16;
1063 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1064 NEW.rank_search := 19;
1065 NEW.rank_address := 16;
1066 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1067 NEW.rank_search := 20;
1068 NEW.rank_address := NEW.rank_search;
1069 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1070 NEW.rank_search := 20;
1071 NEW.rank_address := 0;
1072 -- Irish townlands, tagged as place=locality and locality=townland
1073 IF (NEW.extratags -> 'locality') = 'townland' THEN
1074 NEW.rank_address := 20;
1076 ELSEIF NEW.type in ('neighbourhood') THEN
1077 NEW.rank_search := 22;
1078 NEW.rank_address := 22;
1079 ELSEIF NEW.type in ('house','building') THEN
1080 NEW.rank_search := 30;
1081 NEW.rank_address := NEW.rank_search;
1082 ELSEIF NEW.type in ('houses') THEN
1083 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1084 -- insert new point into place for each derived building
1085 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1086 NEW.rank_search := 28;
1087 NEW.rank_address := 0;
1090 ELSEIF NEW.class = 'boundary' THEN
1091 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1092 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1095 NEW.rank_search := NEW.admin_level * 2;
1096 IF NEW.type = 'administrative' THEN
1097 NEW.rank_address := NEW.rank_search;
1099 NEW.rank_address := 0;
1101 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1102 NEW.rank_search := 22;
1103 NEW.rank_address := NEW.rank_search;
1104 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1105 NEW.rank_search := 18;
1106 NEW.rank_address := 0;
1107 -- any feature more than 5 square miles is probably worth indexing
1108 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1109 NEW.rank_search := 22;
1110 NEW.rank_address := NEW.rank_search;
1111 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1112 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1113 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1115 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1117 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1119 ELSEIF NEW.class = 'waterway' THEN
1120 NEW.rank_search := 17;
1121 NEW.rank_address := 0;
1122 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
1123 NEW.rank_search := 27;
1124 NEW.rank_address := NEW.rank_search;
1125 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1126 NEW.rank_search := 26;
1127 NEW.rank_address := NEW.rank_search;
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 ELSEIF NEW.class = 'mountain_pass' THEN
1134 NEW.rank_search := 20;
1135 NEW.rank_address := 0;
1140 IF NEW.rank_search > 30 THEN
1141 NEW.rank_search := 30;
1144 IF NEW.rank_address > 30 THEN
1145 NEW.rank_address := 30;
1148 IF (NEW.extratags -> 'capital') = 'yes' THEN
1149 NEW.rank_search := NEW.rank_search - 1;
1152 -- a country code make no sense below rank 4 (country)
1153 IF NEW.rank_address < 4 THEN
1154 NEW.calculated_country_code := NULL;
1157 -- Block import below rank 22
1158 -- IF NEW.rank_search > 22 THEN
1162 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1164 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1166 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1167 -- Performance: We just can't handle re-indexing for country level changes
1168 IF st_area(NEW.geometry) < 1 THEN
1169 -- mark items within the geometry for re-indexing
1170 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1172 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1173 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1174 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));
1175 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1176 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));
1179 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1181 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1182 IF NEW.type='postcode' THEN
1184 ELSEIF NEW.rank_search < 16 THEN
1186 ELSEIF NEW.rank_search < 18 THEN
1188 ELSEIF NEW.rank_search < 20 THEN
1190 ELSEIF NEW.rank_search = 21 THEN
1192 ELSEIF NEW.rank_search < 24 THEN
1194 ELSEIF NEW.rank_search < 26 THEN
1195 diameter := 0.002; -- 100 to 200 meters
1196 ELSEIF NEW.rank_search < 28 THEN
1197 diameter := 0.001; -- 50 to 100 meters
1199 IF diameter > 0 THEN
1200 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1201 IF NEW.rank_search >= 26 THEN
1202 -- roads may cause reparenting for >27 rank places
1203 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1204 ELSEIF NEW.rank_search >= 16 THEN
1205 -- up to rank 16, street-less addresses may need reparenting
1206 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);
1208 -- for all other places the search terms may change as well
1209 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);
1215 -- add to tables for special search
1216 -- Note: won't work on initial import because the classtype tables
1217 -- do not yet exist. It won't hurt either.
1218 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1219 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1221 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1222 USING NEW.place_id, ST_Centroid(NEW.geometry);
1226 -- IF NEW.rank_search < 26 THEN
1227 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1236 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1241 place_centroid GEOMETRY;
1243 search_maxdistance FLOAT[];
1244 search_mindistance FLOAT[];
1245 address_havelevel BOOLEAN[];
1246 -- search_scores wordscore[];
1247 -- search_scores_pos INTEGER;
1254 relation_members TEXT[];
1256 linkedplacex RECORD;
1257 search_diameter FLOAT;
1258 search_prevdiameter FLOAT;
1259 search_maxrank INTEGER;
1260 address_maxrank INTEGER;
1261 address_street_word_id INTEGER;
1262 parent_place_id_rank BIGINT;
1267 location_rank_search INTEGER;
1268 location_distance FLOAT;
1269 location_parent GEOMETRY;
1270 location_isaddress BOOLEAN;
1274 default_language TEXT;
1275 name_vector INTEGER[];
1276 nameaddress_vector INTEGER[];
1278 linked_node_id BIGINT;
1284 IF OLD.indexed_status = 100 THEN
1285 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1286 delete from placex where place_id = OLD.place_id;
1290 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1294 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1296 --RAISE WARNING '%',NEW.place_id;
1297 --RAISE WARNING '%', NEW;
1299 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1300 -- Silently do nothing
1304 -- TODO: this test is now redundant?
1305 IF OLD.indexed_status != 0 THEN
1307 NEW.indexed_date = now();
1309 result := deleteSearchName(NEW.partition, NEW.place_id);
1310 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1311 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1312 result := deleteRoad(NEW.partition, NEW.place_id);
1313 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1314 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1316 IF NEW.linked_place_id is not null THEN
1320 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1321 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1325 -- Speed up searches - just use the centroid of the feature
1326 -- cheaper but less acurate
1327 place_centroid := ST_PointOnSurface(NEW.geometry);
1328 NEW.centroid := null;
1330 -- reclaculate country and partition
1331 IF NEW.rank_search = 4 THEN
1332 -- for countries, believe the mapped country code,
1333 -- so that we remain in the right partition if the boundaries
1335 NEW.partition := get_partition(lower(NEW.country_code));
1336 IF NEW.partition = 0 THEN
1337 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1338 NEW.partition := get_partition(NEW.calculated_country_code);
1340 NEW.calculated_country_code := lower(NEW.country_code);
1343 IF NEW.rank_search > 4 THEN
1344 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1345 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1347 NEW.calculated_country_code := NULL;
1349 NEW.partition := get_partition(NEW.calculated_country_code);
1351 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1353 -- Adding ourselves to the list simplifies address calculations later
1354 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1356 -- What level are we searching from
1357 search_maxrank := NEW.rank_search;
1359 -- Thought this wasn't needed but when we add new languages to the country_name table
1360 -- we need to update the existing names
1361 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1362 default_language := get_country_language_code(NEW.calculated_country_code);
1363 IF default_language IS NOT NULL THEN
1364 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1365 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1366 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1367 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1372 -- Initialise the name vector using our name
1373 name_vector := make_keywords(NEW.name);
1374 nameaddress_vector := '{}'::int[];
1376 -- some tag combinations add a special id for search
1377 tagpairid := get_tagpair(NEW.class,NEW.type);
1378 IF tagpairid IS NOT NULL THEN
1379 name_vector := name_vector + tagpairid;
1383 address_havelevel[i] := false;
1386 NEW.importance := null;
1387 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1388 IF NEW.importance IS NULL THEN
1389 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;
1392 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1394 -- For low level elements we inherit from our parent road
1395 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1397 --RAISE WARNING 'finding street for %', NEW;
1399 -- We won't get a better centroid, besides these places are too small to care
1400 NEW.centroid := place_centroid;
1402 NEW.parent_place_id := null;
1404 -- to do that we have to find our parent road
1405 -- Copy data from linked items (points on ways, addr:street links, relations)
1406 -- Note that addr:street links can only be indexed once the street itself is indexed
1407 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1409 -- Is this node part of a relation?
1410 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1412 -- At the moment we only process one type of relation - associatedStreet
1413 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1414 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1415 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1416 --RAISE WARNING 'node in relation %',relation;
1417 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1418 and rank_search = 26 INTO NEW.parent_place_id;
1424 --RAISE WARNING 'x1';
1425 -- Is this node part of a way?
1426 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1427 --RAISE WARNING '%', way;
1428 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1430 --RAISE WARNING '%', location;
1431 -- Way IS a road then we are on it - that must be our road
1432 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1433 --RAISE WARNING 'node in way that is a street %',location;
1434 NEW.parent_place_id := location.place_id;
1437 -- Is the WAY part of a relation
1438 IF NEW.parent_place_id IS NULL THEN
1439 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1441 -- At the moment we only process one type of relation - associatedStreet
1442 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1443 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1444 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1445 --RAISE WARNING 'node in way that is in a relation %',relation;
1446 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1447 and rank_search = 26 INTO NEW.parent_place_id;
1454 -- If the way contains an explicit name of a street copy it
1455 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND location.street IS NOT NULL THEN
1456 --RAISE WARNING 'node in way that has a streetname %',location;
1457 NEW.street := location.street;
1460 -- IF the way contains an explicit name of a place copy it
1461 IF NEW.addr_place IS NULL AND NEW.street IS NULL AND location.addr_place IS NOT NULL THEN
1462 NEW.addr_place := location.addr_place;
1465 -- If this way is a street interpolation line then it is probably as good as we are going to get
1466 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
1467 -- Try and find a way that is close roughly parellel to this line
1468 FOR relation IN SELECT place_id FROM placex
1469 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1470 and st_geometrytype(location.geometry) in ('ST_LineString')
1471 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1472 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1473 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1475 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1476 NEW.parent_place_id := relation.place_id;
1485 --RAISE WARNING 'x2';
1487 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1488 -- Is this way part of a relation?
1489 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1491 -- At the moment we only process one type of relation - associatedStreet
1492 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1493 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1494 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1495 --RAISE WARNING 'way that is in a relation %',relation;
1496 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1497 and rank_search = 26 INTO NEW.parent_place_id;
1504 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1506 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1507 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1508 IF address_street_word_id IS NOT NULL THEN
1509 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1510 NEW.parent_place_id := location.place_id;
1515 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1516 address_street_word_id := get_name_id(make_standard_name(NEW.addr_place));
1517 IF address_street_word_id IS NOT NULL THEN
1518 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1519 NEW.parent_place_id := location.place_id;
1524 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1525 -- Still nothing, just use the nearest road
1526 IF NEW.parent_place_id IS NULL THEN
1527 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1528 NEW.parent_place_id := location.place_id;
1533 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1535 -- If we didn't find any road fallback to standard method
1536 IF NEW.parent_place_id IS NOT NULL THEN
1538 -- Add the street to the address as zero distance to force to front of list
1539 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1540 address_havelevel[26] := true;
1542 -- Import address details from parent, reclculating distance in process
1543 -- 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
1544 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1545 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1547 -- Get the details of the parent road
1548 select * from search_name where place_id = NEW.parent_place_id INTO location;
1549 NEW.calculated_country_code := location.country_code;
1551 --RAISE WARNING '%', NEW.name;
1552 -- If there is no name it isn't searchable, don't bother to create a search record
1553 IF NEW.name is NULL THEN
1557 -- Merge address from parent
1558 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1559 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1561 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1562 -- Just be happy with inheriting from parent road only
1564 IF NEW.rank_search <= 25 THEN
1565 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1568 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);
1575 -- RAISE WARNING ' INDEXING Started:';
1576 -- RAISE WARNING ' INDEXING: %',NEW;
1578 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1580 -- see if we have any special relation members
1581 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1583 -- RAISE WARNING 'get_osm_rel_members, label';
1584 IF relation_members IS NOT NULL THEN
1585 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1587 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1588 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1590 -- If we don't already have one use this as the centre point of the geometry
1591 IF NEW.centroid IS NULL THEN
1592 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1595 -- merge in the label name, re-init word vector
1596 IF NOT linkedPlacex.name IS NULL THEN
1597 NEW.name := linkedPlacex.name || NEW.name;
1598 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1601 -- merge in extra tags
1602 IF NOT linkedPlacex.extratags IS NULL THEN
1603 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1606 IF NOT NEW.extratags ? linkedPlacex.class THEN
1607 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1610 -- mark the linked place (excludes from search results)
1611 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1617 IF NEW.centroid IS NULL THEN
1619 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1621 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1622 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1624 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1625 -- But that can be fixed by explicitly setting the label in the data
1626 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1627 AND NEW.rank_address = linkedPlacex.rank_address THEN
1629 -- If we don't already have one use this as the centre point of the geometry
1630 IF NEW.centroid IS NULL THEN
1631 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1634 -- merge in the name, re-init word vector
1635 IF NOT linkedPlacex.name IS NULL THEN
1636 NEW.name := linkedPlacex.name || NEW.name;
1637 name_vector := make_keywords(NEW.name);
1640 -- merge in extra tags
1641 IF NOT linkedPlacex.extratags IS NULL THEN
1642 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1645 IF NOT NEW.extratags ? linkedPlacex.class THEN
1646 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1649 -- mark the linked place (excludes from search results)
1650 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1652 -- keep a note of the node id in case we need it for wikipedia in a bit
1653 linked_node_id := linkedPlacex.osm_id;
1665 -- Name searches can be done for ways as well as relations
1666 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1668 -- not found one yet? how about doing a name search
1669 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1671 FOR linkedPlacex IN select placex.* from placex WHERE
1672 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1673 AND placex.rank_address = NEW.rank_address
1674 AND placex.place_id != NEW.place_id
1675 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1676 AND st_covers(NEW.geometry, placex.geometry)
1679 -- If we don't already have one use this as the centre point of the geometry
1680 IF NEW.centroid IS NULL THEN
1681 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1684 -- merge in the name, re-init word vector
1685 NEW.name := linkedPlacex.name || NEW.name;
1686 name_vector := make_keywords(NEW.name);
1688 -- merge in extra tags
1689 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1691 IF NOT NEW.extratags ? linkedPlacex.class THEN
1692 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1695 -- mark the linked place (excludes from search results)
1696 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1698 -- keep a note of the node id in case we need it for wikipedia in a bit
1699 linked_node_id := linkedPlacex.osm_id;
1703 IF NEW.centroid IS NOT NULL THEN
1704 place_centroid := NEW.centroid;
1705 -- Place might have had only a name tag before but has now received translations
1706 -- from the linked place. Make sure a name tag for the default language exists in
1708 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1709 default_language := get_country_language_code(NEW.calculated_country_code);
1710 IF default_language IS NOT NULL THEN
1711 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1712 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1713 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1714 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1720 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1721 IF NEW.importance is null THEN
1722 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1724 -- Still null? how about looking it up by the node id
1725 IF NEW.importance IS NULL THEN
1726 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;
1731 -- make sure all names are in the word table
1732 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1733 perform create_country(NEW.name, lower(NEW.country_code));
1736 NEW.parent_place_id = 0;
1737 parent_place_id_rank = 0;
1739 -- convert isin to array of tokenids
1740 isin_tokens := '{}'::int[];
1741 IF NEW.isin IS NOT NULL THEN
1742 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1743 IF array_upper(isin, 1) IS NOT NULL THEN
1744 FOR i IN 1..array_upper(isin, 1) LOOP
1745 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1746 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1747 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1748 isin_tokens := isin_tokens || address_street_word_id;
1751 -- merge word into address vector
1752 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1753 IF address_street_word_id IS NOT NULL THEN
1754 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1759 IF NEW.postcode IS NOT NULL THEN
1760 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1761 IF array_upper(isin, 1) IS NOT NULL THEN
1762 FOR i IN 1..array_upper(isin, 1) LOOP
1763 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1764 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1765 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1766 isin_tokens := isin_tokens || address_street_word_id;
1769 -- merge into address vector
1770 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1771 IF address_street_word_id IS NOT NULL THEN
1772 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1778 -- for the USA we have an additional address table. Merge in zip codes from there too
1779 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1780 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1781 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1782 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1783 isin_tokens := isin_tokens || address_street_word_id;
1785 -- also merge in the single word version
1786 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1787 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1791 -- RAISE WARNING 'ISIN: %', isin_tokens;
1793 -- Process area matches
1794 location_rank_search := 0;
1795 location_distance := 0;
1796 location_parent := NULL;
1797 -- added ourself as address already
1798 address_havelevel[NEW.rank_address] := true;
1799 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1800 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1802 --RAISE WARNING ' AREA: %',location;
1804 IF location.rank_address != location_rank_search THEN
1805 location_rank_search := location.rank_address;
1806 location_distance := location.distance * 1.5;
1809 IF location.distance < location_distance OR NOT location.isguess THEN
1811 location_isaddress := NOT address_havelevel[location.rank_address];
1812 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1813 location_isaddress := ST_Contains(location_parent,location.centroid);
1816 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1817 -- Add it to the list of search terms
1818 IF location.rank_search > 4 THEN
1819 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1821 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1823 IF location_isaddress THEN
1825 address_havelevel[location.rank_address] := true;
1826 IF NOT location.isguess THEN
1827 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1830 IF location.rank_address > parent_place_id_rank THEN
1831 NEW.parent_place_id = location.place_id;
1832 parent_place_id_rank = location.rank_address;
1837 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1843 -- try using the isin value to find parent places
1844 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1845 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1846 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1847 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1849 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1851 --RAISE WARNING ' ISIN: %',location;
1853 IF location.rank_search > 4 THEN
1854 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1855 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1856 address_havelevel[location.rank_address] := true;
1858 IF location.rank_address > parent_place_id_rank THEN
1859 NEW.parent_place_id = location.place_id;
1860 parent_place_id_rank = location.rank_address;
1870 -- for long ways we should add search terms for the entire length
1871 IF st_length(NEW.geometry) > 0.05 THEN
1873 location_rank_search := 0;
1874 location_distance := 0;
1876 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1878 IF location.rank_address != location_rank_search THEN
1879 location_rank_search := location.rank_address;
1880 location_distance := location.distance * 1.5;
1883 IF location.rank_search > 4 AND location.distance < location_distance THEN
1885 -- Add it to the list of search terms
1886 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1887 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1895 -- if we have a name add this to the name search table
1896 IF NEW.name IS NOT NULL THEN
1898 IF NEW.rank_search <= 25 THEN
1899 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1902 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1903 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1906 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);
1910 -- If we've not managed to pick up a better one - default centroid
1911 IF NEW.centroid IS NULL THEN
1912 NEW.centroid := place_centroid;
1922 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1928 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1930 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1931 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1932 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1933 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1935 IF OLD.rank_address < 30 THEN
1937 -- mark everything linked to this place for re-indexing
1938 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1939 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1940 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1942 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1943 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1945 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1946 b := deleteRoad(OLD.partition, OLD.place_id);
1948 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1949 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1950 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1954 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1956 IF OLD.rank_address < 26 THEN
1957 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1960 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1962 IF OLD.name is not null THEN
1963 b := deleteSearchName(OLD.partition, OLD.place_id);
1966 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1968 DELETE FROM place_addressline where place_id = OLD.place_id;
1970 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1972 -- remove from tables for special search
1973 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1974 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1976 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1979 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1987 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1993 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1995 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1996 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1997 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;
1999 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2005 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;
2013 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2018 existingplacex RECORD;
2019 existinggeometry GEOMETRY;
2020 existingplace_id BIGINT;
2025 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2026 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2028 IF FALSE and NEW.osm_type = 'R' THEN
2029 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;
2030 --DEBUG: RAISE WARNING '%', existingplacex;
2033 -- Just block these - lots and pointless
2034 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2035 -- if the name tag was removed, older versions might still be lurking in the place table
2036 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2040 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
2041 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2042 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2043 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2047 -- Patch in additional country names
2048 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2049 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2052 -- Have we already done this place?
2053 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;
2055 -- Get the existing place_id
2056 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;
2058 -- Handle a place changing type by removing the old data
2059 -- My generated 'place' types are causing havok because they overlap with real keys
2060 -- TODO: move them to their own special purpose key/class to avoid collisions
2061 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
2062 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses');
2065 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2066 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2069 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2070 AND st_area(existing.geometry) > 0.02
2071 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2072 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2074 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2075 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2079 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2080 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2082 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2083 IF existingplacex.osm_type IS NULL OR
2084 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2087 IF existingplacex.osm_type IS NOT NULL THEN
2088 -- sanity check: ignore admin_level changes on places with too many active children
2089 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2090 --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;
2091 --LIMIT INDEXING: IF i > 100000 THEN
2092 --LIMIT INDEXING: RETURN null;
2093 --LIMIT INDEXING: END IF;
2096 IF existing.osm_type IS NOT NULL THEN
2097 -- pathological case caused by the triggerless copy into place during initial import
2098 -- force delete even for large areas, it will be reinserted later
2099 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;
2100 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2103 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2104 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2105 street, addr_place, isin, postcode, country_code, extratags, geometry)
2106 values (NEW.osm_type
2122 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2127 -- Various ways to do the update
2129 -- Debug, what's changed?
2131 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2132 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2134 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2135 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2137 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2138 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2140 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2141 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2143 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2144 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2146 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2147 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2149 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2150 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2154 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2155 IF existing.geometry::text != NEW.geometry::text
2156 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2157 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2160 -- Get the version of the geometry actually used (in placex table)
2161 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;
2163 -- Performance limit
2164 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2166 -- 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
2167 update placex set indexed_status = 2 where indexed_status = 0 and
2168 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2169 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2170 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2172 update placex set indexed_status = 2 where indexed_status = 0 and
2173 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2174 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2175 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2181 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2182 IF FALSE AND existingplacex.rank_search < 26
2183 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2184 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2185 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2186 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2187 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2188 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2189 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2192 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2194 IF st_area(NEW.geometry) < 0.5 THEN
2195 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2196 and placex.place_id = place_addressline.place_id and indexed_status = 0
2197 and (rank_search < 28 or name is not null);
2204 -- Anything else has changed - reindex the lot
2205 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2206 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2207 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2208 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2209 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2210 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2211 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2213 -- performance, can't take the load of re-indexing a whole country / huge area
2214 IF st_area(NEW.geometry) < 0.5 THEN
2215 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2216 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2223 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2224 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2225 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2226 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2227 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2228 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2229 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2230 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2231 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2232 OR existing.geometry::text != NEW.geometry::text
2237 housenumber = NEW.housenumber,
2238 street = NEW.street,
2239 addr_place = NEW.addr_place,
2241 postcode = NEW.postcode,
2242 country_code = NEW.country_code,
2243 extratags = NEW.extratags,
2244 admin_level = NEW.admin_level,
2245 geometry = NEW.geometry
2246 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2248 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2249 IF NEW.postcode IS NULL THEN
2250 -- postcode was deleted, no longer retain in placex
2251 DELETE FROM placex where place_id = existingplacex.place_id;
2255 NEW.name := hstore('ref', NEW.postcode);
2260 housenumber = NEW.housenumber,
2261 street = NEW.street,
2262 addr_place = NEW.addr_place,
2264 postcode = NEW.postcode,
2265 country_code = NEW.country_code,
2266 parent_place_id = null,
2267 extratags = NEW.extratags,
2268 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2270 geometry = NEW.geometry
2271 where place_id = existingplacex.place_id;
2275 -- Abort the add (we modified the existing place instead)
2279 $$ LANGUAGE plpgsql;
2281 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2288 IF name is null THEN
2292 search := languagepref;
2294 FOR j IN 1..array_upper(search, 1) LOOP
2295 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2296 return trim(name->search[j]);
2300 -- anything will do as a fallback - just take the first name type thing there is
2301 search := avals(name);
2305 LANGUAGE plpgsql IMMUTABLE;
2307 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2310 searchnodes INTEGER[];
2315 searchnodes := '{}';
2316 FOR j IN 1..array_upper(way_ids, 1) LOOP
2318 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2320 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2321 searchnodes := searchnodes || location.nodes;
2326 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2329 LANGUAGE plpgsql IMMUTABLE;
2331 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2342 search := ARRAY['ref'];
2345 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2348 select rank_address,name,distance,length(name::text) as namelength
2349 from place_addressline join placex on (address_place_id = placex.place_id)
2350 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2351 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2353 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2354 FOR j IN 1..array_upper(search, 1) LOOP
2355 FOR k IN 1..array_upper(location.name, 1) LOOP
2356 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
2357 result[(100 - location.rank_address)] := trim(location.name[k].value);
2358 found := location.rank_address;
2365 RETURN array_to_string(result,', ');
2370 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2382 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2383 currresult := trim(get_name_by_language(location.name, languagepref));
2384 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2385 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2386 prevresult := currresult;
2390 RETURN array_to_string(result,', ');
2395 DROP TYPE IF EXISTS addressline CASCADE;
2396 create type addressline as (
2403 admin_level INTEGER,
2406 rank_address INTEGER,
2410 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2413 for_place_id BIGINT;
2418 countrylocation RECORD;
2419 searchcountrycode varchar(2);
2420 searchhousenumber TEXT;
2421 searchhousename HSTORE;
2422 searchrankaddress INTEGER;
2423 searchpostcode TEXT;
2430 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2431 WHERE place_id = in_place_id
2432 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2434 IF for_place_id IS NULL THEN
2435 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2436 WHERE place_id = in_place_id
2437 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2440 IF for_place_id IS NULL THEN
2441 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2442 WHERE place_id = in_place_id and rank_address = 30
2443 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2446 IF for_place_id IS NULL THEN
2447 for_place_id := in_place_id;
2448 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2449 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2452 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2455 hadcountry := false;
2457 select placex.place_id, osm_type, osm_id,
2458 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2459 class, type, admin_level, true as fromarea, true as isaddress,
2460 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2461 0 as distance, calculated_country_code
2463 where place_id = for_place_id
2465 --RAISE WARNING '%',location;
2466 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2467 searchcountrycode := location.calculated_country_code;
2469 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2470 location.isaddress := FALSE;
2472 IF location.rank_address = 4 AND location.isaddress THEN
2475 IF location.rank_address < 4 AND NOT hadcountry THEN
2476 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2477 IF countryname IS NOT NULL THEN
2478 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2479 RETURN NEXT countrylocation;
2482 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2483 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2484 location.distance)::addressline;
2485 RETURN NEXT countrylocation;
2486 found := location.rank_address;
2490 select placex.place_id, osm_type, osm_id,
2491 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2492 class, type, admin_level, fromarea, isaddress,
2493 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,
2494 distance,calculated_country_code,postcode
2495 from place_addressline join placex on (address_place_id = placex.place_id)
2496 where place_addressline.place_id = for_place_id
2497 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2498 and address_place_id != for_place_id
2499 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2500 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2502 --RAISE WARNING '%',location;
2503 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2504 searchcountrycode := location.calculated_country_code;
2506 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2507 location.isaddress := FALSE;
2509 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2510 searchpostcode := location.postcode;
2512 IF location.rank_address = 4 AND location.isaddress THEN
2515 IF location.rank_address < 4 AND NOT hadcountry THEN
2516 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2517 IF countryname IS NOT NULL THEN
2518 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2519 RETURN NEXT countrylocation;
2522 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2523 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2524 location.distance)::addressline;
2525 RETURN NEXT countrylocation;
2526 found := location.rank_address;
2530 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2531 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2532 IF countryname IS NOT NULL THEN
2533 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2534 RETURN NEXT location;
2538 IF searchcountrycode IS NOT NULL THEN
2539 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2540 RETURN NEXT location;
2543 IF searchhousename IS NOT NULL THEN
2544 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2545 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2546 RETURN NEXT location;
2549 IF searchhousenumber IS NOT NULL THEN
2550 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2551 RETURN NEXT location;
2554 IF searchpostcode IS NOT NULL THEN
2555 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2556 RETURN NEXT location;
2564 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2567 result place_boundingbox;
2568 numfeatures integer;
2570 select * from place_boundingbox into result where place_id = search_place_id;
2571 IF result.place_id IS NULL THEN
2572 -- remove isaddress = true because if there is a matching polygon it always wins
2573 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2574 insert into place_boundingbox select place_id,
2575 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2576 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2577 numfeatures, ST_Area(geometry),
2578 geometry as area from location_area where place_id = search_place_id;
2579 select * from place_boundingbox into result where place_id = search_place_id;
2581 IF result.place_id IS NULL THEN
2583 insert into place_boundingbox select address_place_id,
2584 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2585 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2586 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2587 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2588 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)
2589 where address_place_id = search_place_id
2590 -- and (isaddress = true OR place_id = search_place_id)
2591 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2592 group by address_place_id limit 1;
2593 select * from place_boundingbox into result where place_id = search_place_id;
2600 -- don't do the operation if it would be slow
2601 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2604 result place_boundingbox;
2605 numfeatures integer;
2608 select * from place_boundingbox into result where place_id = search_place_id;
2609 IF result IS NULL AND rank > 14 THEN
2610 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2611 insert into place_boundingbox select place_id,
2612 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2613 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2614 numfeatures, ST_Area(geometry),
2615 geometry as area from location_area where place_id = search_place_id;
2616 select * from place_boundingbox into result where place_id = search_place_id;
2618 IF result IS NULL THEN
2619 select rank_search from placex where place_id = search_place_id into rank;
2622 insert into place_boundingbox select address_place_id,
2623 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2624 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2625 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2626 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2627 from place_addressline join placex using (place_id)
2628 where address_place_id = search_place_id
2629 and (isaddress = true OR place_id = search_place_id)
2630 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2631 group by address_place_id limit 1;
2632 select * from place_boundingbox into result where place_id = search_place_id;
2640 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2643 result place_boundingbox;
2644 numfeatures integer;
2648 housenumber = place.housenumber,
2649 street = place.street,
2650 addr_place = place.addr_place,
2652 postcode = place.postcode,
2653 country_code = place.country_code,
2654 parent_place_id = null
2656 where placex.place_id = search_place_id
2657 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2658 and place.class = placex.class and place.type = placex.type;
2659 update placex set indexed_status = 2 where place_id = search_place_id;
2660 update placex set indexed_status = 0 where place_id = search_place_id;
2666 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2672 ELSEIF rank < 4 THEN
2674 ELSEIF rank < 8 THEN
2676 ELSEIF rank < 12 THEN
2678 ELSEIF rank < 16 THEN
2680 ELSEIF rank = 16 THEN
2682 ELSEIF rank = 17 THEN
2683 RETURN 'Town / Island';
2684 ELSEIF rank = 18 THEN
2685 RETURN 'Village / Hamlet';
2686 ELSEIF rank = 20 THEN
2688 ELSEIF rank = 21 THEN
2689 RETURN 'Postcode Area';
2690 ELSEIF rank = 22 THEN
2691 RETURN 'Croft / Farm / Locality / Islet';
2692 ELSEIF rank = 23 THEN
2693 RETURN 'Postcode Area';
2694 ELSEIF rank = 25 THEN
2695 RETURN 'Postcode Point';
2696 ELSEIF rank = 26 THEN
2697 RETURN 'Street / Major Landmark';
2698 ELSEIF rank = 27 THEN
2699 RETURN 'Minory Street / Path';
2700 ELSEIF rank = 28 THEN
2701 RETURN 'House / Building';
2703 RETURN 'Other: '||rank;
2710 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2716 ELSEIF rank < 2 THEN
2718 ELSEIF rank < 4 THEN
2720 ELSEIF rank = 5 THEN
2722 ELSEIF rank < 8 THEN
2724 ELSEIF rank < 12 THEN
2726 ELSEIF rank < 16 THEN
2728 ELSEIF rank = 16 THEN
2730 ELSEIF rank = 17 THEN
2731 RETURN 'Town / Village / Hamlet';
2732 ELSEIF rank = 20 THEN
2734 ELSEIF rank = 21 THEN
2735 RETURN 'Postcode Area';
2736 ELSEIF rank = 22 THEN
2737 RETURN 'Croft / Farm / Locality / Islet';
2738 ELSEIF rank = 23 THEN
2739 RETURN 'Postcode Area';
2740 ELSEIF rank = 25 THEN
2741 RETURN 'Postcode Point';
2742 ELSEIF rank = 26 THEN
2743 RETURN 'Street / Major Landmark';
2744 ELSEIF rank = 27 THEN
2745 RETURN 'Minory Street / Path';
2746 ELSEIF rank = 28 THEN
2747 RETURN 'House / Building';
2749 RETURN 'Other: '||rank;
2756 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2763 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2764 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2771 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2779 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2781 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2782 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2784 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2792 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2793 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2798 place_centroid GEOMETRY;
2799 out_partition INTEGER;
2800 out_parent_place_id BIGINT;
2802 address_street_word_id INTEGER;
2807 place_centroid := ST_Centroid(pointgeo);
2808 out_partition := get_partition(in_countrycode);
2809 out_parent_place_id := null;
2811 address_street_word_id := get_name_id(make_standard_name(in_street));
2812 IF address_street_word_id IS NOT NULL THEN
2813 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2814 out_parent_place_id := location.place_id;
2818 IF out_parent_place_id IS NULL THEN
2819 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2820 out_parent_place_id := location.place_id;
2824 out_postcode := in_postcode;
2825 IF out_postcode IS NULL THEN
2826 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2828 IF out_postcode IS NULL THEN
2829 out_postcode := getNearestPostcode(out_partition, place_centroid);
2833 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2834 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2835 newpoints := newpoints + 1;
2842 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2849 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2850 IF members[i+1] = member THEN
2851 result := result || members[i];
2860 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2866 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2867 IF members[i+1] = ANY(memberLabels) THEN
2868 RETURN NEXT members[i];
2877 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2878 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2880 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2881 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
2882 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2883 ), '') AS bytea), 'UTF8');
2885 LANGUAGE SQL IMMUTABLE STRICT;
2887 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2891 RETURN decode_url_part(p);
2893 WHEN others THEN return null;
2896 LANGUAGE plpgsql IMMUTABLE;
2898 DROP TYPE wikipedia_article_match CASCADE;
2899 create type wikipedia_article_match as (
2905 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2911 wiki_article_title TEXT;
2912 wiki_article_language TEXT;
2913 result wikipedia_article_match;
2915 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'];
2917 WHILE langs[i] IS NOT NULL LOOP
2918 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2919 IF wiki_article is not null THEN
2920 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2921 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2922 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2923 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2924 wiki_article := replace(wiki_article,' ','_');
2925 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2926 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2927 wiki_article_title := trim(wiki_article);
2928 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;
2930 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2933 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2934 from wikipedia_article
2935 where language = wiki_article_language and
2936 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2938 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2939 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2940 where wikipedia_redirect.language = wiki_article_language and
2941 (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'\\',''))
2942 order by importance desc limit 1 INTO result;
2944 IF result.language is not null THEN
2955 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2956 RETURNS SETOF GEOMETRY
2970 remainingdepth INTEGER;
2975 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2977 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2978 RETURN NEXT geometry;
2982 remainingdepth := maxdepth - 1;
2983 area := ST_AREA(geometry);
2984 IF remainingdepth < 1 OR area < maxarea THEN
2985 RETURN NEXT geometry;
2989 xmin := st_xmin(geometry);
2990 xmax := st_xmax(geometry);
2991 ymin := st_ymin(geometry);
2992 ymax := st_ymax(geometry);
2993 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2995 -- if the geometry completely covers the box don't bother to slice any more
2996 IF ST_AREA(secbox) = area THEN
2997 RETURN NEXT geometry;
3001 xmid := (xmin+xmax)/2;
3002 ymid := (ymin+ymax)/2;
3005 FOR seg IN 1..4 LOOP
3008 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
3011 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
3014 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3017 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3020 IF st_intersects(geometry, secbox) THEN
3021 secgeo := st_intersection(geometry, secbox);
3022 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3023 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3024 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3026 RETURN NEXT geo.geom;
3038 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3039 RETURNS SETOF GEOMETRY
3044 -- 10000000000 is ~~ 1x1 degree
3045 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3046 RETURN NEXT geo.geom;
3054 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3058 osmtype character(1);
3062 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3063 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3064 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3065 -- force delete from place/placex by making it a very small geometry
3066 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;
3067 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3074 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3082 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3083 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3084 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3085 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3086 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3087 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));
3088 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3089 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));
3095 ELSEIF rank < 18 THEN
3097 ELSEIF rank < 20 THEN
3099 ELSEIF rank = 21 THEN
3101 ELSEIF rank < 24 THEN
3103 ELSEIF rank < 26 THEN
3104 diameter := 0.002; -- 100 to 200 meters
3105 ELSEIF rank < 28 THEN
3106 diameter := 0.001; -- 50 to 100 meters
3108 IF diameter > 0 THEN
3110 -- roads may cause reparenting for >27 rank places
3111 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3112 ELSEIF rank >= 16 THEN
3113 -- up to rank 16, street-less addresses may need reparenting
3114 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);
3116 -- for all other places the search terms may change as well
3117 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);