1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
8 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
15 LANGUAGE plpgsql IMMUTABLE;
17 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
23 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
29 LANGUAGE plpgsql IMMUTABLE;
31 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
37 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
38 NEWgeometry := ST_buffer(NEWgeometry,0);
39 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
40 RETURN ST_SetSRID(ST_Point(0,0),4326);
46 LANGUAGE plpgsql IMMUTABLE;
48 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
53 -- RAISE WARNING '%',place;
54 NEWgeometry := ST_PointOnSurface(place);
55 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
56 -- NEWgeometry := ST_buffer(NEWgeometry,0);
57 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
61 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
64 LANGUAGE plpgsql IMMUTABLE;
66 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
67 AS '{modulepath}/nominatim.so', 'transliteration'
68 LANGUAGE c IMMUTABLE STRICT;
70 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
71 AS '{modulepath}/nominatim.so', 'gettokenstring'
72 LANGUAGE c IMMUTABLE STRICT;
74 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
79 o := gettokenstring(transliteration(name));
80 RETURN trim(substr(o,1,length(o)));
83 LANGUAGE 'plpgsql' IMMUTABLE;
85 -- returns NULL if the word is too common
86 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
91 return_word_id INTEGER;
94 lookup_token := trim(lookup_word);
95 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
96 IF return_word_id IS NULL THEN
97 return_word_id := nextval('seq_word');
98 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
100 IF count > get_maxwordfreq() THEN
101 return_word_id := NULL;
104 RETURN return_word_id;
109 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
114 return_word_id INTEGER;
116 lookup_token := ' '||trim(lookup_word);
117 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
118 IF return_word_id IS NULL THEN
119 return_word_id := nextval('seq_word');
120 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
122 RETURN return_word_id;
127 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
132 return_word_id INTEGER;
134 lookup_token := ' '||trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
168 return_word_id INTEGER;
170 lookup_token := lookup_class||'='||lookup_type;
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := lookup_class||'='||lookup_type;
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
190 RETURN return_word_id;
195 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
200 return_word_id INTEGER;
202 lookup_token := ' '||trim(lookup_word);
203 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
204 IF return_word_id IS NULL THEN
205 return_word_id := nextval('seq_word');
206 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
208 RETURN return_word_id;
213 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
218 nospace_lookup_token TEXT;
219 return_word_id INTEGER;
221 lookup_token := ' '||trim(lookup_word);
222 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
223 IF return_word_id IS NULL THEN
224 return_word_id := nextval('seq_word');
225 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
226 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
227 -- IF ' '||nospace_lookup_token != lookup_token THEN
228 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
231 RETURN return_word_id;
236 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
241 RETURN getorcreate_name_id(lookup_word, '');
246 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
251 return_word_id INTEGER;
253 lookup_token := trim(lookup_word);
254 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
255 RETURN return_word_id;
258 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
265 return_word_id INTEGER;
267 lookup_token := ' '||trim(lookup_word);
268 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
269 RETURN return_word_id;
272 LANGUAGE plpgsql IMMUTABLE;
274 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
279 return_word_ids INTEGER[];
281 lookup_token := ' '||trim(lookup_word);
282 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
283 RETURN return_word_ids;
286 LANGUAGE plpgsql IMMUTABLE;
288 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
295 IF array_upper(a, 1) IS NULL THEN
298 IF array_upper(b, 1) IS NULL THEN
302 FOR i IN 1..array_upper(b, 1) LOOP
303 IF NOT (ARRAY[b[i]] <@ r) THEN
310 LANGUAGE plpgsql IMMUTABLE;
312 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
321 FOR item IN SELECT (each(src)).* LOOP
323 s := make_standard_name(item.value);
324 w := getorcreate_country(s, lookup_country_code);
326 words := regexp_split_to_array(item.value, E'[,;()]');
327 IF array_upper(words, 1) != 1 THEN
328 FOR j IN 1..array_upper(words, 1) LOOP
329 s := make_standard_name(words[j]);
331 w := getorcreate_country(s, lookup_country_code);
340 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
350 result := '{}'::INTEGER[];
352 FOR item IN SELECT (each(src)).* LOOP
354 s := make_standard_name(item.value);
356 w := getorcreate_name_id(s, item.value);
358 IF not(ARRAY[w] <@ result) THEN
359 result := result || w;
362 w := getorcreate_word_id(s);
364 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
365 result := result || w;
368 words := string_to_array(s, ' ');
369 IF array_upper(words, 1) IS NOT NULL THEN
370 FOR j IN 1..array_upper(words, 1) LOOP
371 IF (words[j] != '') THEN
372 w = getorcreate_word_id(words[j]);
373 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
374 result := result || w;
380 words := regexp_split_to_array(item.value, E'[,;()]');
381 IF array_upper(words, 1) != 1 THEN
382 FOR j IN 1..array_upper(words, 1) LOOP
383 s := make_standard_name(words[j]);
385 w := getorcreate_word_id(s);
386 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
387 result := result || w;
393 s := regexp_replace(item.value, '市$', '');
394 IF s != item.value THEN
395 s := make_standard_name(s);
397 w := getorcreate_name_id(s, item.value);
398 IF NOT (ARRAY[w] <@ result) THEN
399 result := result || w;
409 LANGUAGE plpgsql IMMUTABLE;
411 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
421 result := '{}'::INTEGER[];
423 s := make_standard_name(src);
424 w := getorcreate_name_id(s, src);
426 IF NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 w := getorcreate_word_id(s);
432 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
433 result := result || w;
436 words := string_to_array(s, ' ');
437 IF array_upper(words, 1) IS NOT NULL THEN
438 FOR j IN 1..array_upper(words, 1) LOOP
439 IF (words[j] != '') THEN
440 w = getorcreate_word_id(words[j]);
441 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
448 words := regexp_split_to_array(src, E'[,;()]');
449 IF array_upper(words, 1) != 1 THEN
450 FOR j IN 1..array_upper(words, 1) LOOP
451 s := make_standard_name(words[j]);
453 w := getorcreate_word_id(s);
454 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
455 result := result || w;
461 s := regexp_replace(src, '市$', '');
463 s := make_standard_name(s);
465 w := getorcreate_name_id(s, src);
466 IF NOT (ARRAY[w] <@ result) THEN
467 result := result || w;
475 LANGUAGE plpgsql IMMUTABLE;
477 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
484 IF (wordscores is null OR words is null) THEN
489 FOR idxword in 1 .. array_upper(words, 1) LOOP
490 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
491 IF wordscores[idxscores].word = words[idxword] THEN
492 result := result + wordscores[idxscores].score;
500 LANGUAGE plpgsql IMMUTABLE;
502 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
505 place_centre GEOMETRY;
508 place_centre := ST_PointOnSurface(place);
510 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
512 -- Try for a OSM polygon
513 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
520 -- Try for OSM fallback data
521 -- The order is to deal with places like HongKong that are 'states' within another polygon
522 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
524 RETURN nearcountry.country_code;
527 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
529 -- Natural earth data
530 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
532 RETURN nearcountry.country_code;
535 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
538 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
540 RETURN nearcountry.country_code;
543 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
545 -- Natural earth data
546 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
548 RETURN nearcountry.country_code;
551 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
552 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
554 -- RETURN nearcountry.country_code;
557 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
559 -- Still not in a country - try nearest within ~12 miles of a country
560 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
561 -- order by st_distance(geometry, place) limit 1
563 -- RETURN nearcountry.country_code;
569 LANGUAGE plpgsql IMMUTABLE;
571 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
576 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
578 RETURN lower(nearcountry.country_default_language_code);
583 LANGUAGE plpgsql IMMUTABLE;
585 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
590 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
592 RETURN lower(nearcountry.country_default_language_codes);
597 LANGUAGE plpgsql IMMUTABLE;
599 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
604 FOR nearcountry IN select partition from country_name where country_code = in_country_code
606 RETURN nearcountry.partition;
611 LANGUAGE plpgsql IMMUTABLE;
613 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
617 DELETE FROM location_area where place_id = OLD_place_id;
618 -- TODO:location_area
624 CREATE OR REPLACE FUNCTION add_location(
626 country_code varchar(2),
630 rank_address INTEGER,
645 IF rank_search > 25 THEN
646 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
649 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
651 x := deleteLocationArea(partition, place_id, rank_search);
654 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
657 centroid := ST_Centroid(geometry);
659 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
660 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
663 ELSEIF rank_search < 26 THEN
666 IF rank_address = 0 THEN
668 ELSEIF rank_search <= 14 THEN
670 ELSEIF rank_search <= 15 THEN
672 ELSEIF rank_search <= 16 THEN
674 ELSEIF rank_search <= 17 THEN
676 ELSEIF rank_search <= 21 THEN
678 ELSEIF rank_search = 25 THEN
682 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
684 secgeo := ST_Buffer(geometry, diameter);
685 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
690 secgeo := ST_Buffer(geometry, 0.0002);
691 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
694 secgeo := ST_Buffer(geometry, 0.001);
695 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
704 CREATE OR REPLACE FUNCTION update_location(
707 place_country_code varchar(2),
710 rank_address INTEGER,
718 b := deleteLocationArea(partition, place_id, rank_search);
719 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
720 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
725 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
736 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
737 FOR childplace IN select * from search_name,place_addressline
738 where address_place_id = parent_place_id
739 and search_name.place_id = place_addressline.place_id
741 delete from search_name where place_id = childplace.place_id;
742 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
743 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
745 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
746 childplace.name_vector := childplace.name_vector || to_add;
748 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
749 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
750 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
758 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
761 newkeywords INTEGER[];
762 addedkeywords INTEGER[];
763 removedkeywords INTEGER[];
767 newkeywords := make_keywords(name);
768 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
769 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
770 where place_id = OLD_place_id into addedkeywords, removedkeywords;
772 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
774 IF #removedkeywords > 0 THEN
775 -- abort due to tokens removed
779 IF #addedkeywords > 0 THEN
780 -- short circuit - no changes
784 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
785 RETURN search_name_add_words(OLD_place_id, addedkeywords);
791 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
803 orginalstartnumber INTEGER;
804 originalnumberrange INTEGER;
809 search_place_id BIGINT;
813 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
815 ELSEIF interpolationtype = 'all' THEN
817 ELSEIF interpolationtype ~ '^\d+$' THEN
818 stepsize := interpolationtype::INTEGER;
823 select nodes from planet_osm_ways where id = wayid INTO waynodes;
825 IF array_upper(waynodes, 1) IS NULL THEN
829 select postcode, geometry from placex where osm_type = 'W' and osm_id = wayid
830 INTO defpostalcode, linegeo;
832 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
839 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
841 -- If there is a place of a type other than place/house, use that because
842 -- it is guaranteed to be the original node. For place/house types use the
843 -- one with the smallest id because the original node was created first.
844 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
845 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;
846 IF search_place_id IS NOT NULL THEN
847 select * from placex where place_id = search_place_id INTO nextnode;
849 IF nodeidpos < array_upper(waynodes, 1) THEN
850 -- Make sure that the point is actually on the line. That might
851 -- be a bit paranoid but ensures that the algorithm still works
852 -- should osm2pgsql attempt to repair geometries.
853 splitline := split_line_on_node(linegeo, nextnode.geometry);
854 sectiongeo := ST_GeometryN(splitline, 1);
855 IF ST_GeometryType(ST_GeometryN(splitline, 2)) = 'ST_LineString' THEN
856 linegeo := ST_GeometryN(splitline, 2);
859 sectiongeo = linegeo;
861 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
863 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
864 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
865 AND ST_GeometryType(linegeo) = 'ST_LineString' THEN
867 IF (startnumber > endnumber) THEN
868 housenum := endnumber;
869 endnumber := startnumber;
870 startnumber := housenum;
871 sectiongeo := ST_Reverse(sectiongeo);
873 orginalstartnumber := startnumber;
874 originalnumberrange := endnumber - startnumber;
876 startnumber := startnumber + stepsize;
877 -- correct for odd/even
878 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
879 startnumber := startnumber - 1;
881 endnumber := endnumber - 1;
883 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
884 FOR housenum IN startnumber..endnumber BY stepsize LOOP
885 -- this should really copy postcodes but it puts a huge burden on
886 -- the system for no big benefit ideally postcodes should move up to the way
887 insert into placex (osm_type, osm_id, class, type, admin_level,
888 housenumber, street, addr_place, isin, postcode,
889 country_code, parent_place_id, rank_address, rank_search,
890 indexed_status, geometry)
891 values ('N', prevnode.osm_id, 'place', 'house', prevnode.admin_level,
892 housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
893 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search,
894 1, ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
895 newpoints := newpoints + 1;
896 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
900 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
901 prevnode := nextnode;
905 --RAISE WARNING 'interpolation points % ',newpoints;
912 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
918 country_code VARCHAR(2);
919 default_language VARCHAR(10);
923 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
925 -- remove operator tag for most places, messes too much with search_name indexes
926 IF NEW.class not in ('amenity', 'shop') THEN
927 NEW.name := delete(NEW.name, 'operator');
931 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
932 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
936 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
937 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
938 RAISE WARNING 'invalid geometry %',NEW.osm_id;
942 IF NEW.osm_type = 'R' THEN
943 -- invalid multipolygons can crash postgis, don't even bother to try!
946 NEW.geometry := ST_buffer(NEW.geometry,0);
947 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
948 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
953 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
955 NEW.place_id := nextval('seq_place');
956 NEW.indexed_status := 1; --STATUS_NEW
958 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
960 NEW.partition := get_partition(NEW.calculated_country_code);
961 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
963 -- copy 'name' to or from the default language (if there is a default language)
964 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
965 default_language := get_country_language_code(NEW.calculated_country_code);
966 IF default_language IS NOT NULL THEN
967 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
968 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
969 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
970 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
975 IF NEW.admin_level > 15 THEN
976 NEW.admin_level := 15;
979 IF NEW.housenumber IS NOT NULL THEN
980 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
983 IF NEW.osm_type = 'X' THEN
984 -- E'X'ternal records should already be in the right format so do nothing
986 NEW.rank_search := 30;
987 NEW.rank_address := NEW.rank_search;
989 -- By doing in postgres we have the country available to us - currently only used for postcode
990 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
992 IF NEW.postcode IS NULL THEN
993 -- most likely just a part of a multipolygon postcode boundary, throw it away
997 NEW.name := hstore('ref', NEW.postcode);
999 IF NEW.calculated_country_code = 'gb' THEN
1001 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1002 NEW.rank_search := 25;
1003 NEW.rank_address := 5;
1004 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1005 NEW.rank_search := 23;
1006 NEW.rank_address := 5;
1007 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1008 NEW.rank_search := 21;
1009 NEW.rank_address := 5;
1012 ELSEIF NEW.calculated_country_code = 'sg' THEN
1014 IF NEW.postcode ~ '^([0-9]{6})$' THEN
1015 NEW.rank_search := 25;
1016 NEW.rank_address := 11;
1019 ELSEIF NEW.calculated_country_code = 'de' THEN
1021 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1022 NEW.rank_search := 21;
1023 NEW.rank_address := 11;
1027 -- Guess at the postcode format and coverage (!)
1028 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1029 NEW.rank_search := 21;
1030 NEW.rank_address := 11;
1032 -- Does it look splitable into and area and local code?
1033 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1035 IF postcode IS NOT NULL THEN
1036 NEW.rank_search := 25;
1037 NEW.rank_address := 11;
1038 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1039 NEW.rank_search := 21;
1040 NEW.rank_address := 11;
1045 ELSEIF NEW.class = 'place' THEN
1046 IF NEW.type in ('continent') THEN
1047 NEW.rank_search := 2;
1048 NEW.rank_address := NEW.rank_search;
1049 NEW.calculated_country_code := NULL;
1050 ELSEIF NEW.type in ('sea') THEN
1051 NEW.rank_search := 2;
1052 NEW.rank_address := 0;
1053 NEW.calculated_country_code := NULL;
1054 ELSEIF NEW.type in ('country') THEN
1055 NEW.rank_search := 4;
1056 NEW.rank_address := NEW.rank_search;
1057 ELSEIF NEW.type in ('state') THEN
1058 NEW.rank_search := 8;
1059 NEW.rank_address := NEW.rank_search;
1060 ELSEIF NEW.type in ('region') THEN
1061 NEW.rank_search := 18; -- dropped from previous value of 10
1062 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1063 ELSEIF NEW.type in ('county') THEN
1064 NEW.rank_search := 12;
1065 NEW.rank_address := NEW.rank_search;
1066 ELSEIF NEW.type in ('city') THEN
1067 NEW.rank_search := 16;
1068 NEW.rank_address := NEW.rank_search;
1069 ELSEIF NEW.type in ('island') THEN
1070 NEW.rank_search := 17;
1071 NEW.rank_address := 0;
1072 ELSEIF NEW.type in ('town') THEN
1073 NEW.rank_search := 18;
1074 NEW.rank_address := 16;
1075 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1076 NEW.rank_search := 19;
1077 NEW.rank_address := 16;
1078 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1079 NEW.rank_search := 20;
1080 NEW.rank_address := NEW.rank_search;
1081 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1082 NEW.rank_search := 20;
1083 NEW.rank_address := 0;
1084 -- Irish townlands, tagged as place=locality and locality=townland
1085 IF (NEW.extratags -> 'locality') = 'townland' THEN
1086 NEW.rank_address := 20;
1088 ELSEIF NEW.type in ('neighbourhood') THEN
1089 NEW.rank_search := 22;
1090 NEW.rank_address := 22;
1091 ELSEIF NEW.type in ('house','building') THEN
1092 NEW.rank_search := 30;
1093 NEW.rank_address := NEW.rank_search;
1094 ELSEIF NEW.type in ('houses') THEN
1095 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1096 -- insert new point into place for each derived building
1097 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1098 NEW.rank_search := 28;
1099 NEW.rank_address := 0;
1102 ELSEIF NEW.class = 'boundary' THEN
1103 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1104 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1107 NEW.rank_search := NEW.admin_level * 2;
1108 IF NEW.type = 'administrative' THEN
1109 NEW.rank_address := NEW.rank_search;
1111 NEW.rank_address := 0;
1113 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1114 NEW.rank_search := 22;
1115 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1116 NEW.rank_address := NEW.rank_search;
1118 NEW.rank_address := 0;
1120 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1121 NEW.rank_search := 18;
1122 NEW.rank_address := 0;
1123 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1124 NEW.rank_search := 4;
1125 NEW.rank_address := NEW.rank_search;
1126 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1128 -- any feature more than 5 square miles is probably worth indexing
1129 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1130 NEW.rank_search := 22;
1131 NEW.rank_address := NEW.rank_search;
1132 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1133 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1134 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1136 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1138 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1140 ELSEIF NEW.class = 'waterway' THEN
1141 IF NEW.osm_type = 'R' THEN
1142 NEW.rank_search := 16;
1144 NEW.rank_search := 17;
1146 NEW.rank_address := 0;
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 = 'mountain_pass' THEN
1154 NEW.rank_search := 20;
1155 NEW.rank_address := 0;
1160 IF NEW.rank_search > 30 THEN
1161 NEW.rank_search := 30;
1164 IF NEW.rank_address > 30 THEN
1165 NEW.rank_address := 30;
1168 IF (NEW.extratags -> 'capital') = 'yes' THEN
1169 NEW.rank_search := NEW.rank_search - 1;
1172 -- a country code make no sense below rank 4 (country)
1173 IF NEW.rank_search < 4 THEN
1174 NEW.calculated_country_code := NULL;
1177 -- Block import below rank 22
1178 -- IF NEW.rank_search > 22 THEN
1182 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1184 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1186 IF NEW.rank_address > 0 THEN
1187 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1188 -- Performance: We just can't handle re-indexing for country level changes
1189 IF st_area(NEW.geometry) < 1 THEN
1190 -- mark items within the geometry for re-indexing
1191 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1193 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1194 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1195 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));
1196 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1197 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 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1202 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1203 IF NEW.type='postcode' THEN
1205 ELSEIF NEW.rank_search < 16 THEN
1207 ELSEIF NEW.rank_search < 18 THEN
1209 ELSEIF NEW.rank_search < 20 THEN
1211 ELSEIF NEW.rank_search = 21 THEN
1213 ELSEIF NEW.rank_search < 24 THEN
1215 ELSEIF NEW.rank_search < 26 THEN
1216 diameter := 0.002; -- 100 to 200 meters
1217 ELSEIF NEW.rank_search < 28 THEN
1218 diameter := 0.001; -- 50 to 100 meters
1220 IF diameter > 0 THEN
1221 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1222 IF NEW.rank_search >= 26 THEN
1223 -- roads may cause reparenting for >27 rank places
1224 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1225 ELSEIF NEW.rank_search >= 16 THEN
1226 -- up to rank 16, street-less addresses may need reparenting
1227 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);
1229 -- for all other places the search terms may change as well
1230 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);
1236 -- add to tables for special search
1237 -- Note: won't work on initial import because the classtype tables
1238 -- do not yet exist. It won't hurt either.
1239 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1240 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1242 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1243 USING NEW.place_id, ST_Centroid(NEW.geometry);
1247 -- IF NEW.rank_search < 26 THEN
1248 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1257 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1262 place_centroid GEOMETRY;
1264 search_maxdistance FLOAT[];
1265 search_mindistance FLOAT[];
1266 address_havelevel BOOLEAN[];
1267 -- search_scores wordscore[];
1268 -- search_scores_pos INTEGER;
1275 relation_members TEXT[];
1277 linkedplacex RECORD;
1278 search_diameter FLOAT;
1279 search_prevdiameter FLOAT;
1280 search_maxrank INTEGER;
1281 address_maxrank INTEGER;
1282 address_street_word_id INTEGER;
1283 address_street_word_ids INTEGER[];
1284 parent_place_id_rank BIGINT;
1289 location_rank_search INTEGER;
1290 location_distance FLOAT;
1291 location_parent GEOMETRY;
1292 location_isaddress BOOLEAN;
1296 default_language TEXT;
1297 name_vector INTEGER[];
1298 nameaddress_vector INTEGER[];
1300 linked_node_id BIGINT;
1306 IF OLD.indexed_status = 100 THEN
1307 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1308 delete from placex where place_id = OLD.place_id;
1312 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1316 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1318 --RAISE WARNING '%',NEW.place_id;
1319 --RAISE WARNING '%', NEW;
1321 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1322 -- Silently do nothing
1326 -- TODO: this test is now redundant?
1327 IF OLD.indexed_status != 0 THEN
1329 NEW.indexed_date = now();
1331 result := deleteSearchName(NEW.partition, NEW.place_id);
1332 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1333 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1334 result := deleteRoad(NEW.partition, NEW.place_id);
1335 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1336 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1338 IF NEW.linked_place_id is not null THEN
1342 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1343 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1347 -- Speed up searches - just use the centroid of the feature
1348 -- cheaper but less acurate
1349 place_centroid := ST_PointOnSurface(NEW.geometry);
1350 NEW.centroid := null;
1352 -- reclaculate country and partition
1353 IF NEW.rank_search = 4 THEN
1354 -- for countries, believe the mapped country code,
1355 -- so that we remain in the right partition if the boundaries
1357 NEW.partition := get_partition(lower(NEW.country_code));
1358 IF NEW.partition = 0 THEN
1359 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1360 NEW.partition := get_partition(NEW.calculated_country_code);
1362 NEW.calculated_country_code := lower(NEW.country_code);
1365 IF NEW.rank_search > 4 THEN
1366 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1367 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1369 NEW.calculated_country_code := NULL;
1371 NEW.partition := get_partition(NEW.calculated_country_code);
1373 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1375 -- waterway ways are linked when they are part of a relation and have the same class/type
1376 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1377 FOR relation IN select * from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1379 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1380 IF relation.members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation.members[i],1,1) = 'w' THEN
1381 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.parts[i];
1382 FOR location IN SELECT * FROM placex
1383 WHERE osm_type = 'W' and osm_id = substring(relation.members[i],2,200)::bigint
1384 and class = NEW.class and type = NEW.type
1385 and ( relation.members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1387 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = location.place_id;
1394 -- Adding ourselves to the list simplifies address calculations later
1395 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1397 -- What level are we searching from
1398 search_maxrank := NEW.rank_search;
1400 -- Thought this wasn't needed but when we add new languages to the country_name table
1401 -- we need to update the existing names
1402 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1403 default_language := get_country_language_code(NEW.calculated_country_code);
1404 IF default_language IS NOT NULL THEN
1405 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1406 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1407 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1408 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1413 -- Initialise the name vector using our name
1414 name_vector := make_keywords(NEW.name);
1415 nameaddress_vector := '{}'::int[];
1417 -- some tag combinations add a special id for search
1418 tagpairid := get_tagpair(NEW.class,NEW.type);
1419 IF tagpairid IS NOT NULL THEN
1420 name_vector := name_vector + tagpairid;
1424 address_havelevel[i] := false;
1427 NEW.importance := null;
1428 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1429 IF NEW.importance IS NULL THEN
1430 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;
1433 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1435 -- For low level elements we inherit from our parent road
1436 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1438 --RAISE WARNING 'finding street for %', NEW;
1440 -- We won't get a better centroid, besides these places are too small to care
1441 NEW.centroid := place_centroid;
1443 NEW.parent_place_id := null;
1445 -- to do that we have to find our parent road
1446 -- Copy data from linked items (points on ways, addr:street links, relations)
1447 -- Note that addr:street links can only be indexed once the street itself is indexed
1448 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1450 -- if there is no address information, see if we can get it from a surrounding building
1451 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1452 FOR location IN select * from placex where ST_Covers(geometry, place_centroid) and rank_search > 28 and (housenumber is not null or street is not null or addr_place is not null) AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1454 NEW.housenumber := location.housenumber;
1455 NEW.street := location.street;
1456 NEW.addr_place := location.addr_place;
1460 -- Is this node part of a relation?
1461 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1463 -- At the moment we only process one type of relation - associatedStreet
1464 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1465 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1466 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1467 --RAISE WARNING 'node in relation %',relation;
1468 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1469 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1475 --RAISE WARNING 'x1';
1476 -- Is this node part of a way?
1477 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1478 --RAISE WARNING '%', way;
1479 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1481 --RAISE WARNING '%', location;
1482 -- Way IS a road then we are on it - that must be our road
1483 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1484 --RAISE WARNING 'node in way that is a street %',location;
1485 NEW.parent_place_id := location.place_id;
1488 -- Is the WAY part of a relation
1489 IF NEW.parent_place_id IS NULL THEN
1490 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1492 -- At the moment we only process one type of relation - associatedStreet
1493 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1494 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1495 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1496 --RAISE WARNING 'node in way that is in a relation %',relation;
1497 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1498 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1505 -- If the way contains an explicit name of a street copy it
1506 -- Slightly less strict then above because data is copied from any object.
1507 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1508 --RAISE WARNING 'node in way that has a streetname %',location;
1509 NEW.street := location.street;
1510 NEW.addr_place := location.addr_place;
1513 -- If this way is a street interpolation line then it is probably as good as we are going to get
1514 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
1515 -- Try and find a way that is close roughly parellel to this line
1516 FOR relation IN SELECT place_id FROM placex
1517 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1518 and st_geometrytype(location.geometry) in ('ST_LineString')
1519 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1520 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1521 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1523 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1524 NEW.parent_place_id := relation.place_id;
1533 --RAISE WARNING 'x2';
1535 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1536 -- Is this way part of a relation?
1537 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1539 -- At the moment we only process one type of relation - associatedStreet
1540 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1541 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1542 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1543 --RAISE WARNING 'way that is in a relation %',relation;
1544 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1545 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1552 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1554 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1555 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1556 IF address_street_word_ids IS NOT NULL THEN
1557 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1558 NEW.parent_place_id := location.place_id;
1563 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1564 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1565 IF address_street_word_ids IS NOT NULL THEN
1566 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1567 NEW.parent_place_id := location.place_id;
1572 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1573 -- Still nothing, just use the nearest road
1574 IF NEW.parent_place_id IS NULL THEN
1575 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1576 NEW.parent_place_id := location.place_id;
1581 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1583 -- If we didn't find any road fallback to standard method
1584 IF NEW.parent_place_id IS NOT NULL THEN
1586 -- Add the street to the address as zero distance to force to front of list
1587 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1588 address_havelevel[26] := true;
1590 -- Import address details from parent, reclculating distance in process
1591 -- 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
1592 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1593 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1595 -- Get the details of the parent road
1596 select * from search_name where place_id = NEW.parent_place_id INTO location;
1597 NEW.calculated_country_code := location.country_code;
1599 --RAISE WARNING '%', NEW.name;
1600 -- If there is no name it isn't searchable, don't bother to create a search record
1601 IF NEW.name is NULL THEN
1605 -- Merge address from parent
1606 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1607 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1609 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1610 -- Just be happy with inheriting from parent road only
1612 IF NEW.rank_search <= 25 THEN
1613 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1616 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);
1623 -- RAISE WARNING ' INDEXING Started:';
1624 -- RAISE WARNING ' INDEXING: %',NEW;
1626 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1628 -- see if we have any special relation members
1629 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1631 -- RAISE WARNING 'get_osm_rel_members, label';
1632 IF relation_members IS NOT NULL THEN
1633 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1635 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1636 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1638 -- If we don't already have one use this as the centre point of the geometry
1639 IF NEW.centroid IS NULL THEN
1640 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1643 -- merge in the label name, re-init word vector
1644 IF NOT linkedPlacex.name IS NULL THEN
1645 NEW.name := linkedPlacex.name || NEW.name;
1646 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1649 -- merge in extra tags
1650 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1652 -- mark the linked place (excludes from search results)
1653 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1655 -- keep a note of the node id in case we need it for wikipedia in a bit
1656 linked_node_id := linkedPlacex.osm_id;
1661 IF NEW.centroid IS NULL THEN
1663 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1665 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1666 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1668 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1669 -- But that can be fixed by explicitly setting the label in the data
1670 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1671 AND NEW.rank_address = linkedPlacex.rank_address THEN
1673 -- If we don't already have one use this as the centre point of the geometry
1674 IF NEW.centroid IS NULL THEN
1675 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1678 -- merge in the name, re-init word vector
1679 IF NOT linkedPlacex.name IS NULL THEN
1680 NEW.name := linkedPlacex.name || NEW.name;
1681 name_vector := make_keywords(NEW.name);
1684 -- merge in extra tags
1685 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1687 -- mark the linked place (excludes from search results)
1688 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1690 -- keep a note of the node id in case we need it for wikipedia in a bit
1691 linked_node_id := linkedPlacex.osm_id;
1703 -- Name searches can be done for ways as well as relations
1704 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1706 -- not found one yet? how about doing a name search
1707 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1709 FOR linkedPlacex IN select placex.* from placex WHERE
1710 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1711 AND placex.rank_address = NEW.rank_address
1712 AND placex.place_id != NEW.place_id
1713 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1714 AND st_covers(NEW.geometry, placex.geometry)
1717 -- If we don't already have one use this as the centre point of the geometry
1718 IF NEW.centroid IS NULL THEN
1719 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1722 -- merge in the name, re-init word vector
1723 NEW.name := linkedPlacex.name || NEW.name;
1724 name_vector := make_keywords(NEW.name);
1726 -- merge in extra tags
1727 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1729 -- mark the linked place (excludes from search results)
1730 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1732 -- keep a note of the node id in case we need it for wikipedia in a bit
1733 linked_node_id := linkedPlacex.osm_id;
1737 IF NEW.centroid IS NOT NULL THEN
1738 place_centroid := NEW.centroid;
1739 -- Place might have had only a name tag before but has now received translations
1740 -- from the linked place. Make sure a name tag for the default language exists in
1742 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1743 default_language := get_country_language_code(NEW.calculated_country_code);
1744 IF default_language IS NOT NULL THEN
1745 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1746 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1747 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1748 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1754 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1755 IF NEW.importance is null THEN
1756 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1758 -- Still null? how about looking it up by the node id
1759 IF NEW.importance IS NULL THEN
1760 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;
1765 -- make sure all names are in the word table
1766 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1767 perform create_country(NEW.name, lower(NEW.country_code));
1770 NEW.parent_place_id = 0;
1771 parent_place_id_rank = 0;
1773 -- convert isin to array of tokenids
1774 isin_tokens := '{}'::int[];
1775 IF NEW.isin IS NOT NULL THEN
1776 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1777 IF array_upper(isin, 1) IS NOT NULL THEN
1778 FOR i IN 1..array_upper(isin, 1) LOOP
1779 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1780 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1781 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1782 isin_tokens := isin_tokens || address_street_word_id;
1785 -- merge word into address vector
1786 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1787 IF address_street_word_id IS NOT NULL THEN
1788 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1793 IF NEW.postcode IS NOT NULL THEN
1794 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1795 IF array_upper(isin, 1) IS NOT NULL THEN
1796 FOR i IN 1..array_upper(isin, 1) LOOP
1797 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1798 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1799 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1800 isin_tokens := isin_tokens || address_street_word_id;
1803 -- merge into address vector
1804 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1805 IF address_street_word_id IS NOT NULL THEN
1806 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1812 -- for the USA we have an additional address table. Merge in zip codes from there too
1813 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1814 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1815 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1816 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1817 isin_tokens := isin_tokens || address_street_word_id;
1819 -- also merge in the single word version
1820 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1821 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1825 -- RAISE WARNING 'ISIN: %', isin_tokens;
1827 -- Process area matches
1828 location_rank_search := 0;
1829 location_distance := 0;
1830 location_parent := NULL;
1831 -- added ourself as address already
1832 address_havelevel[NEW.rank_address] := true;
1833 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1834 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1836 --RAISE WARNING ' AREA: %',location;
1838 IF location.rank_address != location_rank_search THEN
1839 location_rank_search := location.rank_address;
1840 location_distance := location.distance * 1.5;
1843 IF location.distance < location_distance OR NOT location.isguess THEN
1845 location_isaddress := NOT address_havelevel[location.rank_address];
1846 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1847 location_isaddress := ST_Contains(location_parent,location.centroid);
1850 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1851 -- Add it to the list of search terms
1852 IF location.rank_search > 4 THEN
1853 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1855 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1857 IF location_isaddress THEN
1859 address_havelevel[location.rank_address] := true;
1860 IF NOT location.isguess THEN
1861 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1864 IF location.rank_address > parent_place_id_rank THEN
1865 NEW.parent_place_id = location.place_id;
1866 parent_place_id_rank = location.rank_address;
1871 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1877 -- try using the isin value to find parent places
1878 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1879 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1880 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1881 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1883 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1885 --RAISE WARNING ' ISIN: %',location;
1887 IF location.rank_search > 4 THEN
1888 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1889 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1890 address_havelevel[location.rank_address] := true;
1892 IF location.rank_address > parent_place_id_rank THEN
1893 NEW.parent_place_id = location.place_id;
1894 parent_place_id_rank = location.rank_address;
1904 -- for long ways we should add search terms for the entire length
1905 IF st_length(NEW.geometry) > 0.05 THEN
1907 location_rank_search := 0;
1908 location_distance := 0;
1910 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1912 IF location.rank_address != location_rank_search THEN
1913 location_rank_search := location.rank_address;
1914 location_distance := location.distance * 1.5;
1917 IF location.rank_search > 4 AND location.distance < location_distance THEN
1919 -- Add it to the list of search terms
1920 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1921 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1929 -- if we have a name add this to the name search table
1930 IF NEW.name IS NOT NULL THEN
1932 IF NEW.rank_search <= 25 THEN
1933 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1936 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1937 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1940 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);
1944 -- If we've not managed to pick up a better one - default centroid
1945 IF NEW.centroid IS NULL THEN
1946 NEW.centroid := place_centroid;
1956 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1962 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1964 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1965 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1966 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1967 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1969 IF OLD.rank_address < 30 THEN
1971 -- mark everything linked to this place for re-indexing
1972 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1973 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1974 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1976 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1977 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1979 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1980 b := deleteRoad(OLD.partition, OLD.place_id);
1982 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1983 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1984 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1988 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1990 IF OLD.rank_address < 26 THEN
1991 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1994 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1996 IF OLD.name is not null THEN
1997 b := deleteSearchName(OLD.partition, OLD.place_id);
2000 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2002 DELETE FROM place_addressline where place_id = OLD.place_id;
2004 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2006 -- remove from tables for special search
2007 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2008 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2010 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2013 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2021 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2027 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2029 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2030 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2031 SELECT bool_or(not (rank_address = 0 or rank_address > 26)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
2033 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2039 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;
2047 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2052 existingplacex RECORD;
2053 existinggeometry GEOMETRY;
2054 existingplace_id BIGINT;
2059 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2060 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2062 IF FALSE and NEW.osm_type = 'R' THEN
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;
2064 --DEBUG: RAISE WARNING '%', existingplacex;
2067 -- remove operator tag for most places, messes too much with search_name indexes
2068 IF NEW.class not in ('amenity', 'shop') THEN
2069 NEW.name := delete(NEW.name, 'operator');
2072 -- Just block these - lots and pointless
2073 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2074 -- if the name tag was removed, older versions might still be lurking in the place table
2075 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2079 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
2080 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2081 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2082 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2086 -- Patch in additional country names
2087 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2088 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2091 -- Have we already done this place?
2092 select * from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existing;
2094 -- Get the existing place_id
2095 select * from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO existingplacex;
2097 -- Handle a place changing type by removing the old data
2098 -- My generated 'place' types are causing havok because they overlap with real keys
2099 -- TODO: move them to their own special purpose key/class to avoid collisions
2100 IF existing.osm_type IS NULL THEN
2101 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2104 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2105 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2108 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2109 AND st_area(existing.geometry) > 0.02
2110 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2111 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2113 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2114 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2118 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2119 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2121 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2122 IF existingplacex.osm_type IS NULL OR
2123 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2126 IF existingplacex.osm_type IS NOT NULL THEN
2127 -- sanity check: ignore admin_level changes on places with too many active children
2128 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2129 --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i;
2130 --LIMIT INDEXING: IF i > 100000 THEN
2131 --LIMIT INDEXING: RETURN null;
2132 --LIMIT INDEXING: END IF;
2135 IF existing.osm_type IS NOT NULL THEN
2136 -- pathological case caused by the triggerless copy into place during initial import
2137 -- force delete even for large areas, it will be reinserted later
2138 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2139 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2142 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2143 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2144 street, addr_place, isin, postcode, country_code, extratags, geometry)
2145 values (NEW.osm_type
2161 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2166 -- Various ways to do the update
2168 -- Debug, what's changed?
2170 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2171 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2173 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2174 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2176 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2177 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2179 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2180 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2182 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2183 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2185 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2186 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2188 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2189 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2193 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2194 IF existing.geometry::text != NEW.geometry::text
2195 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2196 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2199 -- Get the version of the geometry actually used (in placex table)
2200 select geometry from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type into existinggeometry;
2202 -- Performance limit
2203 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2205 -- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong
2206 update placex set indexed_status = 2 where indexed_status = 0 and
2207 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2208 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2209 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2211 update placex set indexed_status = 2 where indexed_status = 0 and
2212 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2213 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2214 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2220 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2221 IF FALSE AND existingplacex.rank_search < 26
2222 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2223 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2224 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2225 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2226 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2227 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2228 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2231 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2233 IF st_area(NEW.geometry) < 0.5 THEN
2234 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2235 and placex.place_id = place_addressline.place_id and indexed_status = 0
2236 and (rank_search < 28 or name is not null);
2243 -- Anything else has changed - reindex the lot
2244 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2245 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2246 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2247 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2248 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2249 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2250 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2252 -- performance, can't take the load of re-indexing a whole country / huge area
2253 IF st_area(NEW.geometry) < 0.5 THEN
2254 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2255 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2262 -- refuse to update multiplpoygons with too many objects, too much of a performance hit
2263 IF ST_NumGeometries(NEW.geometry) > 2000 THEN
2264 RAISE WARNING 'Dropping update of % % because of geometry complexity.', NEW.osm_type, NEW.osm_id;
2268 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2269 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2270 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2271 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2272 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2273 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2274 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2275 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2276 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2277 OR existing.geometry::text != NEW.geometry::text
2282 housenumber = NEW.housenumber,
2283 street = NEW.street,
2284 addr_place = NEW.addr_place,
2286 postcode = NEW.postcode,
2287 country_code = NEW.country_code,
2288 extratags = NEW.extratags,
2289 admin_level = NEW.admin_level,
2290 geometry = NEW.geometry
2291 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2293 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2294 IF NEW.postcode IS NULL THEN
2295 -- postcode was deleted, no longer retain in placex
2296 DELETE FROM placex where place_id = existingplacex.place_id;
2300 NEW.name := hstore('ref', NEW.postcode);
2305 housenumber = NEW.housenumber,
2306 street = NEW.street,
2307 addr_place = NEW.addr_place,
2309 postcode = NEW.postcode,
2310 country_code = NEW.country_code,
2311 parent_place_id = null,
2312 extratags = NEW.extratags,
2313 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2315 geometry = NEW.geometry
2316 where place_id = existingplacex.place_id;
2320 -- Abort the add (we modified the existing place instead)
2324 $$ LANGUAGE plpgsql;
2326 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2333 IF name is null THEN
2337 search := languagepref;
2339 FOR j IN 1..array_upper(search, 1) LOOP
2340 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2341 return trim(name->search[j]);
2345 -- anything will do as a fallback - just take the first name type thing there is
2346 search := avals(name);
2350 LANGUAGE plpgsql IMMUTABLE;
2352 --CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2355 -- searchnodes INTEGER[];
2360 -- searchnodes := '{}';
2361 -- FOR j IN 1..array_upper(way_ids, 1) LOOP
2363 -- select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2365 -- IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2366 -- searchnodes := searchnodes || location.nodes;
2371 -- RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2374 --LANGUAGE plpgsql IMMUTABLE;
2376 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2387 search := ARRAY['ref'];
2390 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2393 select rank_address,name,distance,length(name::text) as namelength
2394 from place_addressline join placex on (address_place_id = placex.place_id)
2395 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2396 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2398 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2399 FOR j IN 1..array_upper(search, 1) LOOP
2400 FOR k IN 1..array_upper(location.name, 1) LOOP
2401 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
2402 result[(100 - location.rank_address)] := trim(location.name[k].value);
2403 found := location.rank_address;
2410 RETURN array_to_string(result,', ');
2415 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2427 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2428 currresult := trim(get_name_by_language(location.name, languagepref));
2429 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2430 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2431 prevresult := currresult;
2435 RETURN array_to_string(result,', ');
2440 DROP TYPE IF EXISTS addressline CASCADE;
2441 create type addressline as (
2448 admin_level INTEGER,
2451 rank_address INTEGER,
2455 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2458 for_place_id BIGINT;
2463 countrylocation RECORD;
2464 searchcountrycode varchar(2);
2465 searchhousenumber TEXT;
2466 searchhousename HSTORE;
2467 searchrankaddress INTEGER;
2468 searchpostcode TEXT;
2475 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2476 WHERE place_id = in_place_id
2477 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2479 IF for_place_id IS NULL THEN
2480 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2481 WHERE place_id = in_place_id
2482 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2485 IF for_place_id IS NULL THEN
2486 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2487 WHERE place_id = in_place_id and rank_address = 30
2488 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2491 IF for_place_id IS NULL THEN
2492 for_place_id := in_place_id;
2493 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2494 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2497 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2500 hadcountry := false;
2502 select placex.place_id, osm_type, osm_id,
2503 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2504 class, type, admin_level, true as fromarea, true as isaddress,
2505 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2506 0 as distance, calculated_country_code, postcode
2508 where place_id = for_place_id
2510 --RAISE WARNING '%',location;
2511 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2512 searchcountrycode := location.calculated_country_code;
2514 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2515 location.isaddress := FALSE;
2517 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2518 searchpostcode := location.postcode;
2520 IF location.rank_address = 4 AND location.isaddress THEN
2523 IF location.rank_address < 4 AND NOT hadcountry THEN
2524 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2525 IF countryname IS NOT NULL THEN
2526 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2527 RETURN NEXT countrylocation;
2530 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2531 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2532 location.distance)::addressline;
2533 RETURN NEXT countrylocation;
2534 found := location.rank_address;
2538 select placex.place_id, osm_type, osm_id,
2539 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2540 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2541 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2542 admin_level, fromarea, isaddress,
2543 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,
2544 distance,calculated_country_code,postcode
2545 from place_addressline join placex on (address_place_id = placex.place_id)
2546 where place_addressline.place_id = for_place_id
2547 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2548 and address_place_id != for_place_id
2549 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2550 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2552 --RAISE WARNING '%',location;
2553 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2554 searchcountrycode := location.calculated_country_code;
2556 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2557 location.isaddress := FALSE;
2559 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2560 searchpostcode := location.postcode;
2562 IF location.rank_address = 4 AND location.isaddress THEN
2565 IF location.rank_address < 4 AND NOT hadcountry THEN
2566 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2567 IF countryname IS NOT NULL THEN
2568 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2569 RETURN NEXT countrylocation;
2572 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2573 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2574 location.distance)::addressline;
2575 RETURN NEXT countrylocation;
2576 found := location.rank_address;
2580 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2581 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2582 IF countryname IS NOT NULL THEN
2583 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2584 RETURN NEXT location;
2588 IF searchcountrycode IS NOT NULL THEN
2589 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2590 RETURN NEXT location;
2593 IF searchhousename IS NOT NULL THEN
2594 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2595 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2596 RETURN NEXT location;
2599 IF searchhousenumber IS NOT NULL THEN
2600 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2601 RETURN NEXT location;
2604 IF searchpostcode IS NOT NULL THEN
2605 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2606 RETURN NEXT location;
2614 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2617 result place_boundingbox;
2618 numfeatures integer;
2620 select * from place_boundingbox into result where place_id = search_place_id;
2621 IF result.place_id IS NULL THEN
2622 -- remove isaddress = true because if there is a matching polygon it always wins
2623 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2624 insert into place_boundingbox select place_id,
2625 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2626 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2627 numfeatures, ST_Area(geometry),
2628 geometry as area from location_area where place_id = search_place_id;
2629 select * from place_boundingbox into result where place_id = search_place_id;
2631 IF result.place_id IS NULL THEN
2633 insert into place_boundingbox select address_place_id,
2634 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2635 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2636 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2637 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2638 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)
2639 where address_place_id = search_place_id
2640 -- and (isaddress = true OR place_id = search_place_id)
2641 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2642 group by address_place_id limit 1;
2643 select * from place_boundingbox into result where place_id = search_place_id;
2650 -- don't do the operation if it would be slow
2651 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2654 result place_boundingbox;
2655 numfeatures integer;
2658 select * from place_boundingbox into result where place_id = search_place_id;
2659 IF result IS NULL AND rank > 14 THEN
2660 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2661 insert into place_boundingbox select place_id,
2662 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2663 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2664 numfeatures, ST_Area(geometry),
2665 geometry as area from location_area where place_id = search_place_id;
2666 select * from place_boundingbox into result where place_id = search_place_id;
2668 IF result IS NULL THEN
2669 select rank_search from placex where place_id = search_place_id into rank;
2672 insert into place_boundingbox select address_place_id,
2673 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2674 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2675 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2676 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2677 from place_addressline join placex using (place_id)
2678 where address_place_id = search_place_id
2679 and (isaddress = true OR place_id = search_place_id)
2680 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2681 group by address_place_id limit 1;
2682 select * from place_boundingbox into result where place_id = search_place_id;
2690 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2693 result place_boundingbox;
2694 numfeatures integer;
2698 housenumber = place.housenumber,
2699 street = place.street,
2700 addr_place = place.addr_place,
2702 postcode = place.postcode,
2703 country_code = place.country_code,
2704 parent_place_id = null
2706 where placex.place_id = search_place_id
2707 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2708 and place.class = placex.class and place.type = placex.type;
2709 update placex set indexed_status = 2 where place_id = search_place_id;
2710 update placex set indexed_status = 0 where place_id = search_place_id;
2716 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2722 ELSEIF rank < 4 THEN
2724 ELSEIF rank < 8 THEN
2726 ELSEIF rank < 12 THEN
2728 ELSEIF rank < 16 THEN
2730 ELSEIF rank = 16 THEN
2732 ELSEIF rank = 17 THEN
2733 RETURN 'Town / Island';
2734 ELSEIF rank = 18 THEN
2735 RETURN 'Village / Hamlet';
2736 ELSEIF rank = 20 THEN
2738 ELSEIF rank = 21 THEN
2739 RETURN 'Postcode Area';
2740 ELSEIF rank = 22 THEN
2741 RETURN 'Croft / Farm / Locality / Islet';
2742 ELSEIF rank = 23 THEN
2743 RETURN 'Postcode Area';
2744 ELSEIF rank = 25 THEN
2745 RETURN 'Postcode Point';
2746 ELSEIF rank = 26 THEN
2747 RETURN 'Street / Major Landmark';
2748 ELSEIF rank = 27 THEN
2749 RETURN 'Minory Street / Path';
2750 ELSEIF rank = 28 THEN
2751 RETURN 'House / Building';
2753 RETURN 'Other: '||rank;
2760 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2766 ELSEIF rank < 2 THEN
2768 ELSEIF rank < 4 THEN
2770 ELSEIF rank = 5 THEN
2772 ELSEIF rank < 8 THEN
2774 ELSEIF rank < 12 THEN
2776 ELSEIF rank < 16 THEN
2778 ELSEIF rank = 16 THEN
2780 ELSEIF rank = 17 THEN
2781 RETURN 'Town / Village / Hamlet';
2782 ELSEIF rank = 20 THEN
2784 ELSEIF rank = 21 THEN
2785 RETURN 'Postcode Area';
2786 ELSEIF rank = 22 THEN
2787 RETURN 'Croft / Farm / Locality / Islet';
2788 ELSEIF rank = 23 THEN
2789 RETURN 'Postcode Area';
2790 ELSEIF rank = 25 THEN
2791 RETURN 'Postcode Point';
2792 ELSEIF rank = 26 THEN
2793 RETURN 'Street / Major Landmark';
2794 ELSEIF rank = 27 THEN
2795 RETURN 'Minory Street / Path';
2796 ELSEIF rank = 28 THEN
2797 RETURN 'House / Building';
2799 RETURN 'Other: '||rank;
2806 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2813 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2814 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2821 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2829 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2831 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2832 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2834 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2842 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2843 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2848 place_centroid GEOMETRY;
2849 out_partition INTEGER;
2850 out_parent_place_id BIGINT;
2852 address_street_word_id INTEGER;
2857 place_centroid := ST_Centroid(pointgeo);
2858 out_partition := get_partition(in_countrycode);
2859 out_parent_place_id := null;
2861 address_street_word_id := get_name_id(make_standard_name(in_street));
2862 IF address_street_word_id IS NOT NULL THEN
2863 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2864 out_parent_place_id := location.place_id;
2868 IF out_parent_place_id IS NULL THEN
2869 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2870 out_parent_place_id := location.place_id;
2874 out_postcode := in_postcode;
2875 IF out_postcode IS NULL THEN
2876 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2878 IF out_postcode IS NULL THEN
2879 out_postcode := getNearestPostcode(out_partition, place_centroid);
2883 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2884 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2885 newpoints := newpoints + 1;
2892 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2899 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2900 IF members[i+1] = member THEN
2901 result := result || members[i];
2910 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2916 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2917 IF members[i+1] = ANY(memberLabels) THEN
2918 RETURN NEXT members[i];
2927 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2928 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2930 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2931 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
2932 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2933 ), '') AS bytea), 'UTF8');
2935 LANGUAGE SQL IMMUTABLE STRICT;
2937 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2941 RETURN decode_url_part(p);
2943 WHEN others THEN return null;
2946 LANGUAGE plpgsql IMMUTABLE;
2948 DROP TYPE wikipedia_article_match CASCADE;
2949 create type wikipedia_article_match as (
2955 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2961 wiki_article_title TEXT;
2962 wiki_article_language TEXT;
2963 result wikipedia_article_match;
2965 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'];
2967 WHILE langs[i] IS NOT NULL LOOP
2968 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2969 IF wiki_article is not null THEN
2970 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2971 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2972 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2973 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2974 wiki_article := replace(wiki_article,' ','_');
2975 IF strpos(wiki_article, ':') IN (3,4) THEN
2976 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2977 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2979 wiki_article_title := trim(wiki_article);
2980 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;
2983 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2984 from wikipedia_article
2985 where language = wiki_article_language and
2986 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2988 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2989 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2990 where wikipedia_redirect.language = wiki_article_language and
2991 (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'\\',''))
2992 order by importance desc limit 1 INTO result;
2994 IF result.language is not null THEN
3005 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
3006 RETURNS SETOF GEOMETRY
3020 remainingdepth INTEGER;
3025 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
3027 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
3028 RETURN NEXT geometry;
3032 remainingdepth := maxdepth - 1;
3033 area := ST_AREA(geometry);
3034 IF remainingdepth < 1 OR area < maxarea THEN
3035 RETURN NEXT geometry;
3039 xmin := st_xmin(geometry);
3040 xmax := st_xmax(geometry);
3041 ymin := st_ymin(geometry);
3042 ymax := st_ymax(geometry);
3043 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
3045 -- if the geometry completely covers the box don't bother to slice any more
3046 IF ST_AREA(secbox) = area THEN
3047 RETURN NEXT geometry;
3051 xmid := (xmin+xmax)/2;
3052 ymid := (ymin+ymax)/2;
3055 FOR seg IN 1..4 LOOP
3058 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
3061 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
3064 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3067 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3070 IF st_intersects(geometry, secbox) THEN
3071 secgeo := st_intersection(geometry, secbox);
3072 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3073 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3074 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3076 RETURN NEXT geo.geom;
3088 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3089 RETURNS SETOF GEOMETRY
3094 -- 10000000000 is ~~ 1x1 degree
3095 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3096 RETURN NEXT geo.geom;
3104 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3108 osmtype character(1);
3112 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3113 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3114 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3115 -- force delete from place/placex by making it a very small geometry
3116 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;
3117 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3124 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3132 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
3133 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3134 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3135 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3136 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3137 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3138 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));
3139 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3140 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));
3146 ELSEIF rank < 18 THEN
3148 ELSEIF rank < 20 THEN
3150 ELSEIF rank = 21 THEN
3152 ELSEIF rank < 24 THEN
3154 ELSEIF rank < 26 THEN
3155 diameter := 0.002; -- 100 to 200 meters
3156 ELSEIF rank < 28 THEN
3157 diameter := 0.001; -- 50 to 100 meters
3159 IF diameter > 0 THEN
3161 -- roads may cause reparenting for >27 rank places
3162 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3163 ELSEIF rank >= 16 THEN
3164 -- up to rank 16, street-less addresses may need reparenting
3165 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);
3167 -- for all other places the search terms may change as well
3168 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);