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 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 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_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
562 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
564 RETURN nearcountry.country_code;
566 RETURN get_country_code(place);
569 LANGUAGE plpgsql IMMUTABLE;
571 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
576 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
578 RETURN lower(nearcountry.country_default_language_code);
583 LANGUAGE plpgsql IMMUTABLE;
585 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
590 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
592 RETURN lower(nearcountry.country_default_language_codes);
597 LANGUAGE plpgsql IMMUTABLE;
599 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
602 place_centre GEOMETRY;
605 FOR nearcountry IN select partition from country_name where country_code = in_country_code
607 RETURN nearcountry.partition;
612 LANGUAGE plpgsql IMMUTABLE;
614 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
618 DELETE FROM location_area where place_id = OLD_place_id;
619 -- TODO:location_area
625 CREATE OR REPLACE FUNCTION add_location(
627 country_code varchar(2),
631 rank_address INTEGER,
646 IF rank_search > 25 THEN
647 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
650 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
652 x := deleteLocationArea(partition, place_id, rank_search);
655 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
658 centroid := ST_Centroid(geometry);
660 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
661 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
664 ELSEIF rank_search < 26 THEN
667 IF rank_address = 0 THEN
669 ELSEIF rank_search <= 14 THEN
671 ELSEIF rank_search <= 15 THEN
673 ELSEIF rank_search <= 16 THEN
675 ELSEIF rank_search <= 17 THEN
677 ELSEIF rank_search <= 21 THEN
679 ELSEIF rank_search = 25 THEN
683 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
685 secgeo := ST_Buffer(geometry, diameter);
686 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
691 secgeo := ST_Buffer(geometry, 0.0002);
692 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
695 secgeo := ST_Buffer(geometry, 0.001);
696 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
705 CREATE OR REPLACE FUNCTION update_location(
708 place_country_code varchar(2),
711 rank_address INTEGER,
719 b := deleteLocationArea(partition, place_id, rank_search);
720 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
721 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
726 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
737 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
738 FOR childplace IN select * from search_name,place_addressline
739 where address_place_id = parent_place_id
740 and search_name.place_id = place_addressline.place_id
742 delete from search_name where place_id = childplace.place_id;
743 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
744 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
746 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
747 childplace.name_vector := childplace.name_vector || to_add;
749 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
750 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
751 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
759 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
762 newkeywords INTEGER[];
763 addedkeywords INTEGER[];
764 removedkeywords INTEGER[];
768 newkeywords := make_keywords(name);
769 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
770 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
771 where place_id = OLD_place_id into addedkeywords, removedkeywords;
773 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
775 IF #removedkeywords > 0 THEN
776 -- abort due to tokens removed
780 IF #addedkeywords > 0 THEN
781 -- short circuit - no changes
785 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
786 RETURN search_name_add_words(OLD_place_id, addedkeywords);
792 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
804 orginalstartnumber INTEGER;
805 originalnumberrange INTEGER;
808 search_place_id BIGINT;
811 havefirstpoint BOOLEAN;
815 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
817 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
818 select nodes from planet_osm_ways where id = wayid INTO waynodes;
819 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
820 IF array_upper(waynodes, 1) IS NOT NULL THEN
822 havefirstpoint := false;
824 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
826 -- If there is a place of a type other than place/house, use that because
827 -- it is guaranteed to be the original node. For place/house types use the
828 -- one with the smallest id because the original node was created first.
829 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
830 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;
831 IF search_place_id IS NULL THEN
832 -- if no such node exists, create a record of the right type
833 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and type = 'house' limit 1 INTO nextnode;
834 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
835 IF nextnode.geometry IS NULL THEN
836 -- we don't have any information about this point, most likely
837 -- because an excerpt was updated and the node never imported
838 -- because the interpolation is outside the region of the excerpt.
843 select * from placex where place_id = search_place_id INTO nextnode;
846 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
848 IF havefirstpoint THEN
850 -- add point to the line string
851 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
852 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
854 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
856 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
858 IF startnumber != endnumber THEN
860 linestr := linestr || ')';
861 --RAISE WARNING 'linestr %',linestr;
862 linegeo := ST_GeomFromText(linestr,4326);
863 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
864 IF (startnumber > endnumber) THEN
865 housenum := endnumber;
866 endnumber := startnumber;
867 startnumber := housenum;
868 linegeo := ST_Reverse(linegeo);
870 orginalstartnumber := startnumber;
871 originalnumberrange := endnumber - startnumber;
873 -- Too much broken data worldwide for this test to be worth using
874 -- IF originalnumberrange > 500 THEN
875 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
878 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
879 startnumber := startnumber + 1;
882 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
883 startnumber := startnumber + 2;
885 ELSE -- everything else assumed to be 'all'
886 startnumber := startnumber + 1;
890 endnumber := endnumber - 1;
891 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
892 FOR housenum IN startnumber..endnumber BY stepsize LOOP
893 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
894 -- ideally postcodes should move up to the way
895 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, addr_place, isin, postcode,
896 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
897 values ('N',prevnode.osm_id, 'place', 'house', prevnode.admin_level, housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
898 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
899 newpoints := newpoints + 1;
900 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
903 havefirstpoint := false;
907 IF NOT havefirstpoint THEN
908 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
909 IF startnumber IS NOT NULL AND startnumber > 0 THEN
910 havefirstpoint := true;
911 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
912 prevnode := nextnode;
914 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
920 --RAISE WARNING 'interpolation points % ',newpoints;
927 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
933 country_code VARCHAR(2);
934 default_language VARCHAR(10);
938 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
941 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
942 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
946 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
947 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
948 RAISE WARNING 'invalid geometry %',NEW.osm_id;
952 IF NEW.osm_type = 'R' THEN
953 -- invalid multipolygons can crash postgis, don't even bother to try!
956 NEW.geometry := ST_buffer(NEW.geometry,0);
957 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
958 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
963 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
965 NEW.place_id := nextval('seq_place');
966 NEW.indexed_status := 1; --STATUS_NEW
968 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
970 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
971 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
973 -- copy 'name' to or from the default language (if there is a default language)
974 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
975 default_language := get_country_language_code(NEW.calculated_country_code);
976 IF default_language IS NOT NULL THEN
977 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
978 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
979 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
980 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
985 IF NEW.admin_level > 15 THEN
986 NEW.admin_level := 15;
989 IF NEW.housenumber IS NOT NULL THEN
990 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
993 IF NEW.osm_type = 'X' THEN
994 -- E'X'ternal records should already be in the right format so do nothing
996 NEW.rank_search := 30;
997 NEW.rank_address := NEW.rank_search;
999 -- By doing in postgres we have the country available to us - currently only used for postcode
1000 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
1002 IF NEW.postcode IS NULL THEN
1003 -- most likely just a part of a multipolygon postcode boundary, throw it away
1007 NEW.name := hstore('ref', NEW.postcode);
1009 IF NEW.calculated_country_code = 'gb' THEN
1011 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1012 NEW.rank_search := 25;
1013 NEW.rank_address := 5;
1014 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1015 NEW.rank_search := 23;
1016 NEW.rank_address := 5;
1017 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1018 NEW.rank_search := 21;
1019 NEW.rank_address := 5;
1022 ELSEIF NEW.calculated_country_code = 'de' THEN
1024 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1025 NEW.rank_search := 21;
1026 NEW.rank_address := 11;
1030 -- Guess at the postcode format and coverage (!)
1031 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1032 NEW.rank_search := 21;
1033 NEW.rank_address := 11;
1035 -- Does it look splitable into and area and local code?
1036 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1038 IF postcode IS NOT NULL THEN
1039 NEW.rank_search := 25;
1040 NEW.rank_address := 11;
1041 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1042 NEW.rank_search := 21;
1043 NEW.rank_address := 11;
1048 ELSEIF NEW.class = 'place' THEN
1049 IF NEW.type in ('continent') THEN
1050 NEW.rank_search := 2;
1051 NEW.rank_address := NEW.rank_search;
1052 NEW.calculated_country_code := NULL;
1053 ELSEIF NEW.type in ('sea') THEN
1054 NEW.rank_search := 2;
1055 NEW.rank_address := 0;
1056 NEW.calculated_country_code := NULL;
1057 ELSEIF NEW.type in ('country') THEN
1058 NEW.rank_search := 4;
1059 NEW.rank_address := NEW.rank_search;
1060 ELSEIF NEW.type in ('state') THEN
1061 NEW.rank_search := 8;
1062 NEW.rank_address := NEW.rank_search;
1063 ELSEIF NEW.type in ('region') THEN
1064 NEW.rank_search := 18; -- dropped from previous value of 10
1065 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1066 ELSEIF NEW.type in ('county') THEN
1067 NEW.rank_search := 12;
1068 NEW.rank_address := NEW.rank_search;
1069 ELSEIF NEW.type in ('city') THEN
1070 NEW.rank_search := 16;
1071 NEW.rank_address := NEW.rank_search;
1072 ELSEIF NEW.type in ('island') THEN
1073 NEW.rank_search := 17;
1074 NEW.rank_address := 0;
1075 ELSEIF NEW.type in ('town') THEN
1076 NEW.rank_search := 18;
1077 NEW.rank_address := 16;
1078 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1079 NEW.rank_search := 19;
1080 NEW.rank_address := 16;
1081 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1082 NEW.rank_search := 18;
1083 NEW.rank_address := 17;
1084 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1085 NEW.rank_search := 17;
1086 NEW.rank_address := 18;
1087 ELSEIF NEW.type in ('moor') THEN
1088 NEW.rank_search := 17;
1089 NEW.rank_address := 0;
1090 ELSEIF NEW.type in ('national_park') THEN
1091 NEW.rank_search := 18;
1092 NEW.rank_address := 18;
1093 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1094 NEW.rank_search := 20;
1095 NEW.rank_address := NEW.rank_search;
1096 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1097 NEW.rank_search := 20;
1098 NEW.rank_address := 0;
1099 -- Irish townlands, tagged as place=locality and locality=townland
1100 IF (NEW.extratags -> 'locality') = 'townland' THEN
1101 NEW.rank_address := 20;
1103 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1104 NEW.rank_search := 22;
1105 NEW.rank_address := 22;
1106 ELSEIF NEW.type in ('airport','street') THEN
1107 NEW.rank_search := 26;
1108 NEW.rank_address := NEW.rank_search;
1109 ELSEIF NEW.type in ('house','building') THEN
1110 NEW.rank_search := 30;
1111 NEW.rank_address := NEW.rank_search;
1112 ELSEIF NEW.type in ('houses') THEN
1113 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1114 -- insert new point into place for each derived building
1115 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1116 NEW.rank_search := 28;
1117 NEW.rank_address := 0;
1120 ELSEIF NEW.class = 'boundary' THEN
1121 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1122 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1125 NEW.rank_search := NEW.admin_level * 2;
1126 NEW.rank_address := NEW.rank_search;
1127 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1128 NEW.rank_search := 22;
1129 NEW.rank_address := NEW.rank_search;
1130 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1131 NEW.rank_search := 18;
1132 NEW.rank_address := 0;
1133 -- any feature more than 5 square miles is probably worth indexing
1134 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1135 NEW.rank_search := 22;
1136 NEW.rank_address := NEW.rank_search;
1137 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1138 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1139 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1141 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1143 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1145 ELSEIF NEW.class = 'waterway' THEN
1146 NEW.rank_address := 17;
1147 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
1148 NEW.rank_search := 27;
1149 NEW.rank_address := NEW.rank_search;
1150 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1151 NEW.rank_search := 26;
1152 NEW.rank_address := NEW.rank_search;
1153 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1154 NEW.rank_search := 4;
1155 NEW.rank_address := NEW.rank_search;
1156 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1158 ELSEIF NEW.class = 'mountain_pass' THEN
1159 NEW.rank_search := 20;
1160 NEW.rank_address := 0;
1165 IF NEW.rank_search > 30 THEN
1166 NEW.rank_search := 30;
1169 IF NEW.rank_address > 30 THEN
1170 NEW.rank_address := 30;
1173 IF (NEW.extratags -> 'capital') = 'yes' THEN
1174 NEW.rank_search := NEW.rank_search - 1;
1177 -- a country code make no sense below rank 4 (country)
1178 IF NEW.rank_address < 4 THEN
1179 NEW.calculated_country_code := NULL;
1182 -- Block import below rank 22
1183 -- IF NEW.rank_search > 22 THEN
1187 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1189 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1191 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1192 -- Performance: We just can't handle re-indexing for country level changes
1193 IF st_area(NEW.geometry) < 1 THEN
1194 -- mark items within the geometry for re-indexing
1195 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1197 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1198 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1199 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));
1200 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1201 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));
1204 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1206 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1207 IF NEW.type='postcode' THEN
1209 ELSEIF NEW.rank_search < 16 THEN
1211 ELSEIF NEW.rank_search < 18 THEN
1213 ELSEIF NEW.rank_search < 20 THEN
1215 ELSEIF NEW.rank_search = 21 THEN
1217 ELSEIF NEW.rank_search < 24 THEN
1219 ELSEIF NEW.rank_search < 26 THEN
1220 diameter := 0.002; -- 100 to 200 meters
1221 ELSEIF NEW.rank_search < 28 THEN
1222 diameter := 0.001; -- 50 to 100 meters
1224 IF diameter > 0 THEN
1225 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1226 IF NEW.rank_search >= 26 THEN
1227 -- roads may cause reparenting for >27 rank places
1228 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1229 ELSEIF NEW.rank_search >= 16 THEN
1230 -- up to rank 16, street-less addresses may need reparenting
1231 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);
1233 -- for all other places the search terms may change as well
1234 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);
1240 -- add to tables for special search
1241 -- Note: won't work on initial import because the classtype tables
1242 -- do not yet exist. It won't hurt either.
1243 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1244 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1246 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1247 USING NEW.place_id, ST_Centroid(NEW.geometry);
1251 -- IF NEW.rank_search < 26 THEN
1252 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1261 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1266 place_centroid GEOMETRY;
1268 search_maxdistance FLOAT[];
1269 search_mindistance FLOAT[];
1270 address_havelevel BOOLEAN[];
1271 -- search_scores wordscore[];
1272 -- search_scores_pos INTEGER;
1279 relation_members TEXT[];
1281 linkedplacex RECORD;
1282 search_diameter FLOAT;
1283 search_prevdiameter FLOAT;
1284 search_maxrank INTEGER;
1285 address_maxrank INTEGER;
1286 address_street_word_id INTEGER;
1287 parent_place_id_rank BIGINT;
1292 location_rank_search INTEGER;
1293 location_distance FLOAT;
1294 location_parent GEOMETRY;
1295 location_isaddress BOOLEAN;
1299 default_language TEXT;
1300 name_vector INTEGER[];
1301 nameaddress_vector INTEGER[];
1303 linked_node_id BIGINT;
1309 IF OLD.indexed_status = 100 THEN
1310 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1311 delete from placex where place_id = OLD.place_id;
1315 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1319 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1321 --RAISE WARNING '%',NEW.place_id;
1322 --RAISE WARNING '%', NEW;
1324 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1325 -- Silently do nothing
1329 -- TODO: this test is now redundant?
1330 IF OLD.indexed_status != 0 THEN
1332 NEW.indexed_date = now();
1334 result := deleteSearchName(NEW.partition, NEW.place_id);
1335 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1336 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1337 result := deleteRoad(NEW.partition, NEW.place_id);
1338 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1339 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1341 IF NEW.linked_place_id is not null THEN
1345 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1346 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1350 -- Speed up searches - just use the centroid of the feature
1351 -- cheaper but less acurate
1352 place_centroid := ST_PointOnSurface(NEW.geometry);
1353 NEW.centroid := null;
1355 -- reclaculate country and partition
1356 IF NEW.rank_search >= 4 THEN
1357 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1358 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1360 NEW.calculated_country_code := NULL;
1362 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1363 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1365 -- Adding ourselves to the list simplifies address calculations later
1366 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1368 -- What level are we searching from
1369 search_maxrank := NEW.rank_search;
1371 -- Thought this wasn't needed but when we add new languages to the country_name table
1372 -- we need to update the existing names
1373 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1374 default_language := get_country_language_code(NEW.calculated_country_code);
1375 IF default_language IS NOT NULL THEN
1376 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1377 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1378 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1379 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1384 -- Initialise the name vector using our name
1385 name_vector := make_keywords(NEW.name);
1386 nameaddress_vector := '{}'::int[];
1388 -- some tag combinations add a special id for search
1389 tagpairid := get_tagpair(NEW.class,NEW.type);
1390 IF tagpairid IS NOT NULL THEN
1391 name_vector := name_vector + tagpairid;
1395 address_havelevel[i] := false;
1398 NEW.importance := null;
1399 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1400 IF NEW.importance IS NULL THEN
1401 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;
1404 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1406 -- For low level elements we inherit from our parent road
1407 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1409 --RAISE WARNING 'finding street for %', NEW;
1411 -- We won't get a better centroid, besides these places are too small to care
1412 NEW.centroid := place_centroid;
1414 NEW.parent_place_id := null;
1416 -- to do that we have to find our parent road
1417 -- Copy data from linked items (points on ways, addr:street links, relations)
1418 -- Note that addr:street links can only be indexed once the street itself is indexed
1419 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1421 -- Is this node part of a relation?
1422 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1424 -- At the moment we only process one type of relation - associatedStreet
1425 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1426 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1427 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1428 --RAISE WARNING 'node in relation %',relation;
1429 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1430 and rank_search = 26 INTO NEW.parent_place_id;
1436 --RAISE WARNING 'x1';
1437 -- Is this node part of a way?
1438 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1439 --RAISE WARNING '%', way;
1440 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1442 --RAISE WARNING '%', location;
1443 -- Way IS a road then we are on it - that must be our road
1444 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1445 --RAISE WARNING 'node in way that is a street %',location;
1446 NEW.parent_place_id := location.place_id;
1449 -- Is the WAY part of a relation
1450 IF NEW.parent_place_id IS NULL THEN
1451 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1453 -- At the moment we only process one type of relation - associatedStreet
1454 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1455 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1456 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1457 --RAISE WARNING 'node in way that is in a relation %',relation;
1458 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1459 and rank_search = 26 INTO NEW.parent_place_id;
1466 -- If the way contains an explicit name of a street copy it
1467 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND location.street IS NOT NULL THEN
1468 --RAISE WARNING 'node in way that has a streetname %',location;
1469 NEW.street := location.street;
1472 -- IF the way contains an explicit name of a place copy it
1473 IF NEW.addr_place IS NULL AND NEW.street IS NULL AND location.addr_place IS NOT NULL THEN
1474 NEW.addr_place := location.addr_place;
1477 -- If this way is a street interpolation line then it is probably as good as we are going to get
1478 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
1479 -- Try and find a way that is close roughly parellel to this line
1480 FOR relation IN SELECT place_id FROM placex
1481 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1482 and st_geometrytype(location.geometry) in ('ST_LineString')
1483 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1484 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1485 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1487 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1488 NEW.parent_place_id := relation.place_id;
1497 --RAISE WARNING 'x2';
1499 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1500 -- Is this way part of a relation?
1501 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1503 -- At the moment we only process one type of relation - associatedStreet
1504 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1505 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1506 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1507 --RAISE WARNING 'way that is in a relation %',relation;
1508 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1509 and rank_search = 26 INTO NEW.parent_place_id;
1516 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1518 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1519 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1520 IF address_street_word_id IS NOT NULL THEN
1521 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1522 NEW.parent_place_id := location.place_id;
1527 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1528 address_street_word_id := get_name_id(make_standard_name(NEW.addr_place));
1529 IF address_street_word_id IS NOT NULL THEN
1530 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1531 NEW.parent_place_id := location.place_id;
1536 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1537 -- Still nothing, just use the nearest road
1538 IF NEW.parent_place_id IS NULL THEN
1539 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1540 NEW.parent_place_id := location.place_id;
1545 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1547 -- If we didn't find any road fallback to standard method
1548 IF NEW.parent_place_id IS NOT NULL THEN
1550 -- Add the street to the address as zero distance to force to front of list
1551 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1552 address_havelevel[26] := true;
1554 -- Import address details from parent, reclculating distance in process
1555 -- 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
1556 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1557 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1559 -- Get the details of the parent road
1560 select * from search_name where place_id = NEW.parent_place_id INTO location;
1561 NEW.calculated_country_code := location.country_code;
1563 --RAISE WARNING '%', NEW.name;
1564 -- If there is no name it isn't searchable, don't bother to create a search record
1565 IF NEW.name is NULL THEN
1569 -- Merge address from parent
1570 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1571 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1573 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1574 -- Just be happy with inheriting from parent road only
1576 IF NEW.rank_search <= 25 THEN
1577 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1580 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);
1587 -- RAISE WARNING ' INDEXING Started:';
1588 -- RAISE WARNING ' INDEXING: %',NEW;
1590 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1592 -- see if we have any special relation members
1593 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1595 -- RAISE WARNING 'get_osm_rel_members, label';
1596 IF relation_members IS NOT NULL THEN
1597 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1599 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1600 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1602 -- If we don't already have one use this as the centre point of the geometry
1603 IF NEW.centroid IS NULL THEN
1604 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1607 -- merge in the label name, re-init word vector
1608 IF NOT linkedPlacex.name IS NULL THEN
1609 NEW.name := linkedPlacex.name || NEW.name;
1610 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1613 -- merge in extra tags
1614 IF NOT linkedPlacex.extratags IS NULL THEN
1615 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1618 IF NOT NEW.extratags ? linkedPlacex.class THEN
1619 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1622 -- mark the linked place (excludes from search results)
1623 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1629 IF NEW.centroid IS NULL THEN
1631 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1633 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1634 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1636 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1637 -- But that can be fixed by explicitly setting the label in the data
1638 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1639 AND NEW.rank_address = linkedPlacex.rank_address THEN
1641 -- If we don't already have one use this as the centre point of the geometry
1642 IF NEW.centroid IS NULL THEN
1643 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1646 -- merge in the name, re-init word vector
1647 IF NOT linkedPlacex.name IS NULL THEN
1648 NEW.name := linkedPlacex.name || NEW.name;
1649 name_vector := make_keywords(NEW.name);
1652 -- merge in extra tags
1653 IF NOT linkedPlacex.extratags IS NULL THEN
1654 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1657 IF NOT NEW.extratags ? linkedPlacex.class THEN
1658 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1661 -- mark the linked place (excludes from search results)
1662 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1664 -- keep a note of the node id in case we need it for wikipedia in a bit
1665 linked_node_id := linkedPlacex.osm_id;
1677 -- Name searches can be done for ways as well as relations
1678 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1680 -- not found one yet? how about doing a name search
1681 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1683 FOR linkedPlacex IN select placex.* from placex WHERE
1684 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1685 AND placex.rank_address = NEW.rank_address
1686 AND placex.place_id != NEW.place_id
1687 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1688 AND st_covers(NEW.geometry, placex.geometry)
1691 -- If we don't already have one use this as the centre point of the geometry
1692 IF NEW.centroid IS NULL THEN
1693 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1696 -- merge in the name, re-init word vector
1697 NEW.name := linkedPlacex.name || NEW.name;
1698 name_vector := make_keywords(NEW.name);
1700 -- merge in extra tags
1701 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1703 IF NOT NEW.extratags ? linkedPlacex.class THEN
1704 NEW.extratags := NEW.extratags || hstore(linkedPlacex.class, linkedPlacex.type);
1707 -- mark the linked place (excludes from search results)
1708 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1710 -- keep a note of the node id in case we need it for wikipedia in a bit
1711 linked_node_id := linkedPlacex.osm_id;
1715 IF NEW.centroid IS NOT NULL THEN
1716 place_centroid := NEW.centroid;
1717 -- Place might have had only a name tag before but has now received translations
1718 -- from the linked place. Make sure a name tag for the default language exists in
1720 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1721 default_language := get_country_language_code(NEW.calculated_country_code);
1722 IF default_language IS NOT NULL THEN
1723 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1724 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1725 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1726 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1732 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1733 IF NEW.importance is null THEN
1734 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1736 -- Still null? how about looking it up by the node id
1737 IF NEW.importance IS NULL THEN
1738 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;
1743 -- make sure all names are in the word table
1744 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1745 perform create_country(NEW.name, lower(NEW.country_code));
1748 NEW.parent_place_id = 0;
1749 parent_place_id_rank = 0;
1751 -- convert isin to array of tokenids
1752 isin_tokens := '{}'::int[];
1753 IF NEW.isin IS NOT NULL THEN
1754 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1755 IF array_upper(isin, 1) IS NOT NULL THEN
1756 FOR i IN 1..array_upper(isin, 1) LOOP
1757 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1758 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1759 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1760 isin_tokens := isin_tokens || address_street_word_id;
1763 -- merge word into address vector
1764 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1765 IF address_street_word_id IS NOT NULL THEN
1766 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1771 IF NEW.postcode IS NOT NULL THEN
1772 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1773 IF array_upper(isin, 1) IS NOT NULL THEN
1774 FOR i IN 1..array_upper(isin, 1) LOOP
1775 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1776 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1777 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1778 isin_tokens := isin_tokens || address_street_word_id;
1781 -- merge into address vector
1782 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1783 IF address_street_word_id IS NOT NULL THEN
1784 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1790 -- for the USA we have an additional address table. Merge in zip codes from there too
1791 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1792 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1793 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1794 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1795 isin_tokens := isin_tokens || address_street_word_id;
1797 -- also merge in the single word version
1798 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1799 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1803 -- RAISE WARNING 'ISIN: %', isin_tokens;
1805 -- Process area matches
1806 location_rank_search := 0;
1807 location_distance := 0;
1808 location_parent := NULL;
1809 -- added ourself as address already
1810 address_havelevel[NEW.rank_address] := true;
1811 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1812 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1814 --RAISE WARNING ' AREA: %',location;
1816 IF location.rank_address != location_rank_search THEN
1817 location_rank_search := location.rank_address;
1818 location_distance := location.distance * 1.5;
1821 IF location.distance < location_distance OR NOT location.isguess THEN
1823 location_isaddress := NOT address_havelevel[location.rank_address];
1824 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1825 location_isaddress := ST_Contains(location_parent,location.centroid);
1828 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1829 -- Add it to the list of search terms
1830 IF location.rank_search > 4 THEN
1831 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1833 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1835 IF location_isaddress THEN
1837 address_havelevel[location.rank_address] := true;
1838 IF NOT location.isguess THEN
1839 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1842 IF location.rank_address > parent_place_id_rank THEN
1843 NEW.parent_place_id = location.place_id;
1844 parent_place_id_rank = location.rank_address;
1849 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1855 -- try using the isin value to find parent places
1856 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1857 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1858 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1859 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1861 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1863 --RAISE WARNING ' ISIN: %',location;
1865 IF location.rank_search > 4 THEN
1866 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1867 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1868 address_havelevel[location.rank_address] := true;
1870 IF location.rank_address > parent_place_id_rank THEN
1871 NEW.parent_place_id = location.place_id;
1872 parent_place_id_rank = location.rank_address;
1882 -- for long ways we should add search terms for the entire length
1883 IF st_length(NEW.geometry) > 0.05 THEN
1885 location_rank_search := 0;
1886 location_distance := 0;
1888 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1890 IF location.rank_address != location_rank_search THEN
1891 location_rank_search := location.rank_address;
1892 location_distance := location.distance * 1.5;
1895 IF location.rank_search > 4 AND location.distance < location_distance THEN
1897 -- Add it to the list of search terms
1898 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1899 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1907 -- if we have a name add this to the name search table
1908 IF NEW.name IS NOT NULL THEN
1910 IF NEW.rank_search <= 25 THEN
1911 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1914 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1915 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1918 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);
1922 -- If we've not managed to pick up a better one - default centroid
1923 IF NEW.centroid IS NULL THEN
1924 NEW.centroid := place_centroid;
1934 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1940 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1942 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1943 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1944 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1945 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1947 IF OLD.rank_address < 30 THEN
1949 -- mark everything linked to this place for re-indexing
1950 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1951 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1952 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1954 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1955 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1957 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1958 b := deleteRoad(OLD.partition, OLD.place_id);
1960 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1961 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1962 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1966 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1968 IF OLD.rank_address < 26 THEN
1969 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1972 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1974 IF OLD.name is not null THEN
1975 b := deleteSearchName(OLD.partition, OLD.place_id);
1978 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1980 DELETE FROM place_addressline where place_id = OLD.place_id;
1982 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1984 -- remove from tables for special search
1985 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1986 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1988 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1991 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1999 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2005 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2007 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2008 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2009 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2014 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;
2022 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2027 existingplacex RECORD;
2028 existinggeometry GEOMETRY;
2029 existingplace_id BIGINT;
2034 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2035 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2037 IF FALSE and NEW.osm_type = 'R' THEN
2038 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;
2039 --DEBUG: RAISE WARNING '%', existingplacex;
2042 -- Just block these - lots and pointless
2043 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2047 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
2048 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2049 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2050 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2054 -- Patch in additional country names
2055 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2056 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2059 -- Have we already done this place?
2060 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;
2062 -- Get the existing place_id
2063 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;
2065 -- Handle a place changing type by removing the old data
2066 -- My generated 'place' types are causing havok because they overlap with real keys
2067 -- TODO: move them to their own special purpose key/class to avoid collisions
2068 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
2069 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');
2072 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2073 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2076 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2077 AND st_area(existing.geometry) > 0.02
2078 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2079 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2081 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2082 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2086 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2087 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2089 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry
2090 IF existingplacex.osm_type IS NULL THEN
2092 IF existing.osm_type IS NOT NULL THEN
2093 -- pathological case caused by the triggerless copy into place during initial import
2094 -- force delete even for large areas, it will be reinserted later
2095 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;
2096 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2099 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2100 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2101 street, addr_place, isin, postcode, country_code, extratags, geometry)
2102 values (NEW.osm_type
2118 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2123 -- Various ways to do the update
2125 -- Debug, what's changed?
2127 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2128 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2130 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2131 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2133 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2134 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2136 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2137 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2139 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2140 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2142 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2143 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2145 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2146 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2150 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2151 IF existing.geometry::text != NEW.geometry::text
2152 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2153 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2156 -- Get the version of the geometry actually used (in placex table)
2157 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;
2159 -- Performance limit
2160 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2162 -- 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
2163 update placex set indexed_status = 2 where indexed_status = 0 and
2164 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2165 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2166 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2168 update placex set indexed_status = 2 where indexed_status = 0 and
2169 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2170 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2171 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2177 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2178 IF FALSE AND existingplacex.rank_search < 26
2179 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2180 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2181 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2182 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2183 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2184 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2185 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2188 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2190 IF st_area(NEW.geometry) < 0.5 THEN
2191 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2192 and placex.place_id = place_addressline.place_id and indexed_status = 0
2193 and (rank_search < 28 or name is not null);
2200 -- Anything else has changed - reindex the lot
2201 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2202 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2203 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2204 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2205 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2206 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2207 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2209 -- performance, can't take the load of re-indexing a whole country / huge area
2210 IF st_area(NEW.geometry) < 0.5 THEN
2211 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2212 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2219 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2220 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2221 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2222 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2223 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2224 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2225 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2226 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2227 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2228 OR existing.geometry::text != NEW.geometry::text
2233 housenumber = NEW.housenumber,
2234 street = NEW.street,
2235 addr_place = NEW.addr_place,
2237 postcode = NEW.postcode,
2238 country_code = NEW.country_code,
2239 extratags = NEW.extratags,
2240 admin_level = NEW.admin_level,
2241 geometry = NEW.geometry
2242 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2246 housenumber = NEW.housenumber,
2247 street = NEW.street,
2248 addr_place = NEW.addr_place,
2250 postcode = NEW.postcode,
2251 country_code = NEW.country_code,
2252 parent_place_id = null,
2253 extratags = NEW.extratags,
2254 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2256 geometry = NEW.geometry
2257 where place_id = existingplacex.place_id;
2261 -- Abort the add (we modified the existing place instead)
2265 $$ LANGUAGE plpgsql;
2267 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2274 IF name is null THEN
2278 search := languagepref;
2280 FOR j IN 1..array_upper(search, 1) LOOP
2281 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2282 return trim(name->search[j]);
2286 -- anything will do as a fallback - just take the first name type thing there is
2287 search := avals(name);
2291 LANGUAGE plpgsql IMMUTABLE;
2293 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2296 searchnodes INTEGER[];
2301 searchnodes := '{}';
2302 FOR j IN 1..array_upper(way_ids, 1) LOOP
2304 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2306 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2307 searchnodes := searchnodes || location.nodes;
2312 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2315 LANGUAGE plpgsql IMMUTABLE;
2317 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2328 search := ARRAY['ref'];
2331 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2334 select rank_address,name,distance,length(name::text) as namelength
2335 from place_addressline join placex on (address_place_id = placex.place_id)
2336 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2337 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2339 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2340 FOR j IN 1..array_upper(search, 1) LOOP
2341 FOR k IN 1..array_upper(location.name, 1) LOOP
2342 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
2343 result[(100 - location.rank_address)] := trim(location.name[k].value);
2344 found := location.rank_address;
2351 RETURN array_to_string(result,', ');
2356 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2368 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2369 currresult := trim(get_name_by_language(location.name, languagepref));
2370 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2371 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2372 prevresult := currresult;
2376 RETURN array_to_string(result,', ');
2381 DROP TYPE IF EXISTS addressline CASCADE;
2382 create type addressline as (
2389 admin_level INTEGER,
2392 rank_address INTEGER,
2396 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2399 for_place_id BIGINT;
2404 countrylocation RECORD;
2405 searchcountrycode varchar(2);
2406 searchhousenumber TEXT;
2407 searchhousename HSTORE;
2408 searchrankaddress INTEGER;
2409 searchpostcode TEXT;
2416 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2417 WHERE place_id = in_place_id
2418 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2420 IF for_place_id IS NULL THEN
2421 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2422 WHERE place_id = in_place_id
2423 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2426 IF for_place_id IS NULL THEN
2427 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2428 WHERE place_id = in_place_id and rank_address = 30
2429 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2432 IF for_place_id IS NULL THEN
2433 for_place_id := in_place_id;
2434 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2435 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2438 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2441 hadcountry := false;
2443 select placex.place_id, osm_type, osm_id,
2444 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2445 class, type, admin_level, true as fromarea, true as isaddress,
2446 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2447 0 as distance, calculated_country_code
2449 where place_id = for_place_id
2451 --RAISE WARNING '%',location;
2452 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2453 searchcountrycode := location.calculated_country_code;
2455 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2456 location.isaddress := FALSE;
2458 IF location.rank_address = 4 AND location.isaddress THEN
2461 IF location.rank_address < 4 AND NOT hadcountry THEN
2462 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2463 IF countryname IS NOT NULL THEN
2464 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2465 RETURN NEXT countrylocation;
2468 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2469 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2470 location.distance)::addressline;
2471 RETURN NEXT countrylocation;
2472 found := location.rank_address;
2476 select placex.place_id, osm_type, osm_id,
2477 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2478 class, type, admin_level, fromarea, isaddress,
2479 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,
2480 distance,calculated_country_code
2481 from place_addressline join placex on (address_place_id = placex.place_id)
2482 where place_addressline.place_id = for_place_id
2483 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2484 and address_place_id != for_place_id
2485 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2486 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2488 --RAISE WARNING '%',location;
2489 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2490 searchcountrycode := location.calculated_country_code;
2492 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2493 location.isaddress := FALSE;
2495 IF location.rank_address = 4 AND location.isaddress THEN
2498 IF location.rank_address < 4 AND NOT hadcountry THEN
2499 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2500 IF countryname IS NOT NULL THEN
2501 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2502 RETURN NEXT countrylocation;
2505 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2506 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2507 location.distance)::addressline;
2508 RETURN NEXT countrylocation;
2509 found := location.rank_address;
2513 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2514 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2515 IF countryname IS NOT NULL THEN
2516 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2517 RETURN NEXT location;
2521 IF searchcountrycode IS NOT NULL THEN
2522 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2523 RETURN NEXT location;
2526 IF searchhousename IS NOT NULL THEN
2527 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2528 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2529 RETURN NEXT location;
2532 IF searchhousenumber IS NOT NULL THEN
2533 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2534 RETURN NEXT location;
2537 IF searchpostcode IS NOT NULL THEN
2538 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2539 RETURN NEXT location;
2547 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2550 result place_boundingbox;
2551 numfeatures integer;
2553 select * from place_boundingbox into result where place_id = search_place_id;
2554 IF result.place_id IS NULL THEN
2555 -- remove isaddress = true because if there is a matching polygon it always wins
2556 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2557 insert into place_boundingbox select place_id,
2558 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2559 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2560 numfeatures, ST_Area(geometry),
2561 geometry as area from location_area where place_id = search_place_id;
2562 select * from place_boundingbox into result where place_id = search_place_id;
2564 IF result.place_id IS NULL THEN
2566 insert into place_boundingbox select address_place_id,
2567 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2568 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2569 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2570 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2571 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)
2572 where address_place_id = search_place_id
2573 -- and (isaddress = true OR place_id = search_place_id)
2574 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2575 group by address_place_id limit 1;
2576 select * from place_boundingbox into result where place_id = search_place_id;
2583 -- don't do the operation if it would be slow
2584 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2587 result place_boundingbox;
2588 numfeatures integer;
2591 select * from place_boundingbox into result where place_id = search_place_id;
2592 IF result IS NULL AND rank > 14 THEN
2593 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2594 insert into place_boundingbox select place_id,
2595 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2596 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2597 numfeatures, ST_Area(geometry),
2598 geometry as area from location_area where place_id = search_place_id;
2599 select * from place_boundingbox into result where place_id = search_place_id;
2601 IF result IS NULL THEN
2602 select rank_search from placex where place_id = search_place_id into rank;
2605 insert into place_boundingbox select address_place_id,
2606 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2607 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2608 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2609 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2610 from place_addressline join placex using (place_id)
2611 where address_place_id = search_place_id
2612 and (isaddress = true OR place_id = search_place_id)
2613 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2614 group by address_place_id limit 1;
2615 select * from place_boundingbox into result where place_id = search_place_id;
2623 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2626 result place_boundingbox;
2627 numfeatures integer;
2631 housenumber = place.housenumber,
2632 street = place.street,
2633 addr_place = place.addr_place,
2635 postcode = place.postcode,
2636 country_code = place.country_code,
2637 parent_place_id = null
2639 where placex.place_id = search_place_id
2640 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2641 and place.class = placex.class and place.type = placex.type;
2642 update placex set indexed_status = 2 where place_id = search_place_id;
2643 update placex set indexed_status = 0 where place_id = search_place_id;
2649 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2655 ELSEIF rank < 4 THEN
2657 ELSEIF rank < 8 THEN
2659 ELSEIF rank < 12 THEN
2661 ELSEIF rank < 16 THEN
2663 ELSEIF rank = 16 THEN
2665 ELSEIF rank = 17 THEN
2666 RETURN 'Town / Island';
2667 ELSEIF rank = 18 THEN
2668 RETURN 'Village / Hamlet';
2669 ELSEIF rank = 20 THEN
2671 ELSEIF rank = 21 THEN
2672 RETURN 'Postcode Area';
2673 ELSEIF rank = 22 THEN
2674 RETURN 'Croft / Farm / Locality / Islet';
2675 ELSEIF rank = 23 THEN
2676 RETURN 'Postcode Area';
2677 ELSEIF rank = 25 THEN
2678 RETURN 'Postcode Point';
2679 ELSEIF rank = 26 THEN
2680 RETURN 'Street / Major Landmark';
2681 ELSEIF rank = 27 THEN
2682 RETURN 'Minory Street / Path';
2683 ELSEIF rank = 28 THEN
2684 RETURN 'House / Building';
2686 RETURN 'Other: '||rank;
2693 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2699 ELSEIF rank < 2 THEN
2701 ELSEIF rank < 4 THEN
2703 ELSEIF rank = 5 THEN
2705 ELSEIF rank < 8 THEN
2707 ELSEIF rank < 12 THEN
2709 ELSEIF rank < 16 THEN
2711 ELSEIF rank = 16 THEN
2713 ELSEIF rank = 17 THEN
2714 RETURN 'Town / Village / Hamlet';
2715 ELSEIF rank = 20 THEN
2717 ELSEIF rank = 21 THEN
2718 RETURN 'Postcode Area';
2719 ELSEIF rank = 22 THEN
2720 RETURN 'Croft / Farm / Locality / Islet';
2721 ELSEIF rank = 23 THEN
2722 RETURN 'Postcode Area';
2723 ELSEIF rank = 25 THEN
2724 RETURN 'Postcode Point';
2725 ELSEIF rank = 26 THEN
2726 RETURN 'Street / Major Landmark';
2727 ELSEIF rank = 27 THEN
2728 RETURN 'Minory Street / Path';
2729 ELSEIF rank = 28 THEN
2730 RETURN 'House / Building';
2732 RETURN 'Other: '||rank;
2739 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2746 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2747 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2754 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2762 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2764 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2765 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2767 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2775 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2776 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2781 place_centroid GEOMETRY;
2782 out_partition INTEGER;
2783 out_parent_place_id BIGINT;
2785 address_street_word_id INTEGER;
2790 place_centroid := ST_Centroid(pointgeo);
2791 out_partition := get_partition(place_centroid, in_countrycode);
2792 out_parent_place_id := null;
2794 address_street_word_id := get_name_id(make_standard_name(in_street));
2795 IF address_street_word_id IS NOT NULL THEN
2796 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2797 out_parent_place_id := location.place_id;
2801 IF out_parent_place_id IS NULL THEN
2802 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2803 out_parent_place_id := location.place_id;
2807 out_postcode := in_postcode;
2808 IF out_postcode IS NULL THEN
2809 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2811 IF out_postcode IS NULL THEN
2812 out_postcode := getNearestPostcode(out_partition, place_centroid);
2816 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2817 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2818 newpoints := newpoints + 1;
2825 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2832 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2833 IF members[i+1] = member THEN
2834 result := result || members[i];
2843 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2849 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2850 IF members[i+1] = ANY(memberLabels) THEN
2851 RETURN NEXT members[i];
2860 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2861 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2863 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2864 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
2865 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2866 ), '') AS bytea), 'UTF8');
2868 LANGUAGE SQL IMMUTABLE STRICT;
2870 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2874 RETURN decode_url_part(p);
2876 WHEN others THEN return null;
2879 LANGUAGE plpgsql IMMUTABLE;
2881 DROP TYPE wikipedia_article_match CASCADE;
2882 create type wikipedia_article_match as (
2888 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2894 wiki_article_title TEXT;
2895 wiki_article_language TEXT;
2896 result wikipedia_article_match;
2898 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'];
2900 WHILE langs[i] IS NOT NULL LOOP
2901 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2902 IF wiki_article is not null THEN
2903 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2904 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2905 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2906 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2907 wiki_article := replace(wiki_article,' ','_');
2908 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2909 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2910 wiki_article_title := trim(wiki_article);
2911 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;
2913 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2916 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2917 from wikipedia_article
2918 where language = wiki_article_language and
2919 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2921 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2922 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2923 where wikipedia_redirect.language = wiki_article_language and
2924 (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'\\',''))
2925 order by importance desc limit 1 INTO result;
2927 IF result.language is not null THEN
2938 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2939 RETURNS SETOF GEOMETRY
2953 remainingdepth INTEGER;
2958 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2960 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2961 RETURN NEXT geometry;
2965 remainingdepth := maxdepth - 1;
2966 area := ST_AREA(geometry);
2967 IF remainingdepth < 1 OR area < maxarea THEN
2968 RETURN NEXT geometry;
2972 xmin := st_xmin(geometry);
2973 xmax := st_xmax(geometry);
2974 ymin := st_ymin(geometry);
2975 ymax := st_ymax(geometry);
2976 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2978 -- if the geometry completely covers the box don't bother to slice any more
2979 IF ST_AREA(secbox) = area THEN
2980 RETURN NEXT geometry;
2984 xmid := (xmin+xmax)/2;
2985 ymid := (ymin+ymax)/2;
2988 FOR seg IN 1..4 LOOP
2991 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2994 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2997 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3000 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3003 IF st_intersects(geometry, secbox) THEN
3004 secgeo := st_intersection(geometry, secbox);
3005 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3006 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3007 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3009 RETURN NEXT geo.geom;
3021 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3022 RETURNS SETOF GEOMETRY
3027 -- 10000000000 is ~~ 1x1 degree
3028 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3029 RETURN NEXT geo.geom;
3037 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3041 osmtype character(1);
3045 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3046 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3047 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3048 -- force delete from place/placex by making it a very small geometry
3049 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;
3050 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3057 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3065 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3066 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3067 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3068 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3069 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3070 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));
3071 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3072 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));
3078 ELSEIF rank < 18 THEN
3080 ELSEIF rank < 20 THEN
3082 ELSEIF rank = 21 THEN
3084 ELSEIF rank < 24 THEN
3086 ELSEIF rank < 26 THEN
3087 diameter := 0.002; -- 100 to 200 meters
3088 ELSEIF rank < 28 THEN
3089 diameter := 0.001; -- 50 to 100 meters
3091 IF diameter > 0 THEN
3093 -- roads may cause reparenting for >27 rank places
3094 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3095 ELSEIF rank >= 16 THEN
3096 -- up to rank 16, street-less addresses may need reparenting
3097 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);
3099 -- for all other places the search terms may change as well
3100 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);