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, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
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, null, 'place', 'house', null, 0, null);
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, null, lookup_country_code, 0, null);
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, null, lookup_class, lookup_type, null, 0, null);
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, null, 0, null);
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, null, lookup_class, lookup_type, null, 0, op, null);
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, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
226 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
227 -- IF ' '||nospace_lookup_token != lookup_token THEN
228 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
231 RETURN return_word_id;
236 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
241 RETURN getorcreate_name_id(lookup_word, '');
246 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
251 return_word_id INTEGER;
253 lookup_token := trim(lookup_word);
254 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
255 RETURN return_word_id;
258 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
265 return_word_id INTEGER;
267 lookup_token := ' '||trim(lookup_word);
268 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
269 RETURN return_word_id;
272 LANGUAGE plpgsql IMMUTABLE;
274 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
281 IF array_upper(a, 1) IS NULL THEN
284 IF array_upper(b, 1) IS NULL THEN
288 FOR i IN 1..array_upper(b, 1) LOOP
289 IF NOT (ARRAY[b[i]] <@ r) THEN
296 LANGUAGE plpgsql IMMUTABLE;
298 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
307 FOR item IN SELECT (each(src)).* LOOP
309 s := make_standard_name(item.value);
310 w := getorcreate_country(s, lookup_country_code);
312 words := regexp_split_to_array(item.value, E'[,;()]');
313 IF array_upper(words, 1) != 1 THEN
314 FOR j IN 1..array_upper(words, 1) LOOP
315 s := make_standard_name(words[j]);
317 w := getorcreate_country(s, lookup_country_code);
326 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
336 result := '{}'::INTEGER[];
338 FOR item IN SELECT (each(src)).* LOOP
340 s := make_standard_name(item.value);
342 w := getorcreate_name_id(s, item.value);
344 IF not(ARRAY[w] <@ result) THEN
345 result := result || w;
348 words := string_to_array(s, ' ');
349 IF array_upper(words, 1) IS NOT NULL THEN
350 FOR j IN 1..array_upper(words, 1) LOOP
351 IF (words[j] != '') THEN
352 w = getorcreate_word_id(words[j]);
353 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
354 result := result || w;
360 words := regexp_split_to_array(item.value, E'[,;()]');
361 IF array_upper(words, 1) != 1 THEN
362 FOR j IN 1..array_upper(words, 1) LOOP
363 s := make_standard_name(words[j]);
365 w := getorcreate_word_id(s);
366 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
367 result := result || w;
373 s := regexp_replace(item.value, '市$', '');
374 IF s != item.value THEN
375 s := make_standard_name(s);
377 w := getorcreate_name_id(s, item.value);
378 IF NOT (ARRAY[w] <@ result) THEN
379 result := result || w;
389 LANGUAGE plpgsql IMMUTABLE;
391 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
401 result := '{}'::INTEGER[];
403 s := make_standard_name(src);
404 w := getorcreate_name_id(s, src);
406 IF NOT (ARRAY[w] <@ result) THEN
407 result := result || w;
410 words := string_to_array(s, ' ');
411 IF array_upper(words, 1) IS NOT NULL THEN
412 FOR j IN 1..array_upper(words, 1) LOOP
413 IF (words[j] != '') THEN
414 w = getorcreate_word_id(words[j]);
415 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
416 result := result || w;
422 words := regexp_split_to_array(src, E'[,;()]');
423 IF array_upper(words, 1) != 1 THEN
424 FOR j IN 1..array_upper(words, 1) LOOP
425 s := make_standard_name(words[j]);
427 w := getorcreate_word_id(s);
428 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
429 result := result || w;
435 s := regexp_replace(src, '市$', '');
437 s := make_standard_name(s);
439 w := getorcreate_name_id(s, src);
440 IF NOT (ARRAY[w] <@ result) THEN
441 result := result || w;
449 LANGUAGE plpgsql IMMUTABLE;
451 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
458 IF (wordscores is null OR words is null) THEN
463 FOR idxword in 1 .. array_upper(words, 1) LOOP
464 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
465 IF wordscores[idxscores].word = words[idxword] THEN
466 result := result + wordscores[idxscores].score;
474 LANGUAGE plpgsql IMMUTABLE;
476 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
479 place_centre GEOMETRY;
482 place_centre := ST_PointOnSurface(place);
484 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
486 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
488 -- Try for OSM fallback data
489 -- The order is to deal with places like HongKong that are 'states' within another polygon
490 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
492 RETURN nearcountry.country_code;
495 -- Try for a OSM polygon
496 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
498 RETURN nearcountry.country_code;
501 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
503 -- Natural earth data
504 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
506 RETURN nearcountry.country_code;
509 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
512 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
514 RETURN nearcountry.country_code;
517 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
519 -- Natural earth data
520 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
522 RETURN nearcountry.country_code;
525 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
526 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
528 -- RETURN nearcountry.country_code;
531 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
533 -- Still not in a country - try nearest within ~12 miles of a country
534 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
535 -- order by st_distance(geometry, place) limit 1
537 -- RETURN nearcountry.country_code;
543 LANGUAGE plpgsql IMMUTABLE;
545 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
550 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
552 RETURN nearcountry.country_code;
554 RETURN get_country_code(place);
557 LANGUAGE plpgsql IMMUTABLE;
559 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
564 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
566 RETURN lower(nearcountry.country_default_language_code);
571 LANGUAGE plpgsql IMMUTABLE;
573 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
578 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
580 RETURN lower(nearcountry.country_default_language_codes);
585 LANGUAGE plpgsql IMMUTABLE;
587 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
590 place_centre GEOMETRY;
593 FOR nearcountry IN select partition from country_name where country_code = in_country_code
595 RETURN nearcountry.partition;
600 LANGUAGE plpgsql IMMUTABLE;
602 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
606 DELETE FROM location_area where place_id = OLD_place_id;
607 -- TODO:location_area
613 CREATE OR REPLACE FUNCTION add_location(
615 country_code varchar(2),
619 rank_address INTEGER,
634 IF rank_search > 25 THEN
635 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
638 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
640 x := deleteLocationArea(partition, place_id, rank_search);
643 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
646 centroid := ST_Centroid(geometry);
648 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
649 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
652 ELSEIF rank_search < 26 THEN
655 IF rank_address = 0 THEN
657 ELSEIF rank_search <= 14 THEN
659 ELSEIF rank_search <= 15 THEN
661 ELSEIF rank_search <= 16 THEN
663 ELSEIF rank_search <= 17 THEN
665 ELSEIF rank_search <= 21 THEN
667 ELSEIF rank_search = 25 THEN
671 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
673 secgeo := ST_Buffer(geometry, diameter);
674 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
679 secgeo := ST_Buffer(geometry, 0.0002);
680 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
683 secgeo := ST_Buffer(geometry, 0.001);
684 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
693 CREATE OR REPLACE FUNCTION update_location(
696 place_country_code varchar(2),
699 rank_address INTEGER,
707 b := deleteLocationArea(partition, place_id, rank_search);
708 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
709 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
714 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
725 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
726 FOR childplace IN select * from search_name,place_addressline
727 where address_place_id = parent_place_id
728 and search_name.place_id = place_addressline.place_id
730 delete from search_name where place_id = childplace.place_id;
731 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
732 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
734 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
735 childplace.name_vector := childplace.name_vector || to_add;
737 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
738 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
739 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
747 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
750 newkeywords INTEGER[];
751 addedkeywords INTEGER[];
752 removedkeywords INTEGER[];
756 newkeywords := make_keywords(name);
757 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
758 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
759 where place_id = OLD_place_id into addedkeywords, removedkeywords;
761 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
763 IF #removedkeywords > 0 THEN
764 -- abort due to tokens removed
768 IF #addedkeywords > 0 THEN
769 -- short circuit - no changes
773 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
774 RETURN search_name_add_words(OLD_place_id, addedkeywords);
780 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
792 orginalstartnumber INTEGER;
793 originalnumberrange INTEGER;
796 search_place_id BIGINT;
799 havefirstpoint BOOLEAN;
803 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
805 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
806 select nodes from planet_osm_ways where id = wayid INTO waynodes;
807 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
808 IF array_upper(waynodes, 1) IS NOT NULL THEN
810 havefirstpoint := false;
812 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
814 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
815 IF search_place_id IS NULL THEN
816 -- null record of right type
817 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
818 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
819 IF nextnode.geometry IS NULL THEN
820 -- we don't have any information about this point, most likely
821 -- because an excerpt was updated and the node never imported
822 -- because the interpolation is outside the region of the excerpt.
827 select * from placex where place_id = search_place_id INTO nextnode;
830 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
832 IF havefirstpoint THEN
834 -- add point to the line string
835 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
836 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
838 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
840 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
842 IF startnumber != endnumber THEN
844 linestr := linestr || ')';
845 --RAISE WARNING 'linestr %',linestr;
846 linegeo := ST_GeomFromText(linestr,4326);
847 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
848 IF (startnumber > endnumber) THEN
849 housenum := endnumber;
850 endnumber := startnumber;
851 startnumber := housenum;
852 linegeo := ST_Reverse(linegeo);
854 orginalstartnumber := startnumber;
855 originalnumberrange := endnumber - startnumber;
857 -- Too much broken data worldwide for this test to be worth using
858 -- IF originalnumberrange > 500 THEN
859 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
862 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
863 startnumber := startnumber + 1;
866 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
867 startnumber := startnumber + 2;
869 ELSE -- everything else assumed to be 'all'
870 startnumber := startnumber + 1;
874 endnumber := endnumber - 1;
875 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
876 FOR housenum IN startnumber..endnumber BY stepsize LOOP
877 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
878 -- ideally postcodes should move up to the way
879 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
880 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
881 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
882 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
883 newpoints := newpoints + 1;
884 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
887 havefirstpoint := false;
891 IF NOT havefirstpoint THEN
892 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
893 IF startnumber IS NOT NULL AND startnumber > 0 THEN
894 havefirstpoint := true;
895 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
896 prevnode := nextnode;
898 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
904 --RAISE WARNING 'interpolation points % ',newpoints;
911 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
917 country_code VARCHAR(2);
918 default_language VARCHAR(10);
922 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
925 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
926 -- RAISE WARNING 'bad highway %',NEW.osm_id;
929 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
930 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
934 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
935 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
936 RAISE WARNING 'invalid geometry %',NEW.osm_id;
940 IF NEW.osm_type = 'R' THEN
941 -- invalid multipolygons can crash postgis, don't even bother to try!
944 NEW.geometry := ST_buffer(NEW.geometry,0);
945 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
946 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
951 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
953 NEW.place_id := nextval('seq_place');
954 NEW.indexed_status := 1; --STATUS_NEW
956 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
958 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
959 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
961 -- copy 'name' to or from the default language (if there is a default language)
962 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
963 default_language := get_country_language_code(NEW.calculated_country_code);
964 IF default_language IS NOT NULL THEN
965 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
966 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
967 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
968 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
973 IF NEW.admin_level > 15 THEN
974 NEW.admin_level := 15;
977 IF NEW.housenumber IS NOT NULL THEN
978 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
981 IF NEW.osm_type = 'X' THEN
982 -- E'X'ternal records should already be in the right format so do nothing
984 NEW.rank_search := 30;
985 NEW.rank_address := NEW.rank_search;
987 -- By doing in postgres we have the country available to us - currently only used for postcode
988 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
990 IF NEW.postcode IS NULL THEN
991 -- most likely just a part of a multipolygon postcode boundary, throw it away
995 NEW.name := hstore('ref', NEW.postcode);
997 IF NEW.calculated_country_code = 'gb' THEN
999 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1000 NEW.rank_search := 25;
1001 NEW.rank_address := 5;
1002 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1003 NEW.rank_search := 23;
1004 NEW.rank_address := 5;
1005 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1006 NEW.rank_search := 21;
1007 NEW.rank_address := 5;
1010 ELSEIF NEW.calculated_country_code = 'de' THEN
1012 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1013 NEW.rank_search := 21;
1014 NEW.rank_address := 11;
1018 -- Guess at the postcode format and coverage (!)
1019 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1020 NEW.rank_search := 21;
1021 NEW.rank_address := 11;
1023 -- Does it look splitable into and area and local code?
1024 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1026 IF postcode IS NOT NULL THEN
1027 NEW.rank_search := 25;
1028 NEW.rank_address := 11;
1029 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1030 NEW.rank_search := 21;
1031 NEW.rank_address := 11;
1036 ELSEIF NEW.class = 'place' THEN
1037 IF NEW.type in ('continent') THEN
1038 NEW.rank_search := 2;
1039 NEW.rank_address := NEW.rank_search;
1040 NEW.calculated_country_code := NULL;
1041 ELSEIF NEW.type in ('sea') THEN
1042 NEW.rank_search := 2;
1043 NEW.rank_address := 0;
1044 NEW.calculated_country_code := NULL;
1045 ELSEIF NEW.type in ('country') THEN
1046 NEW.rank_search := 4;
1047 NEW.rank_address := NEW.rank_search;
1048 ELSEIF NEW.type in ('state') THEN
1049 NEW.rank_search := 8;
1050 NEW.rank_address := NEW.rank_search;
1051 ELSEIF NEW.type in ('region') THEN
1052 NEW.rank_search := 18; -- dropped from previous value of 10
1053 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1054 ELSEIF NEW.type in ('county') THEN
1055 NEW.rank_search := 12;
1056 NEW.rank_address := NEW.rank_search;
1057 ELSEIF NEW.type in ('city') THEN
1058 NEW.rank_search := 16;
1059 NEW.rank_address := NEW.rank_search;
1060 ELSEIF NEW.type in ('island') THEN
1061 NEW.rank_search := 17;
1062 NEW.rank_address := 0;
1063 ELSEIF NEW.type in ('town') THEN
1064 NEW.rank_search := 18;
1065 NEW.rank_address := 16;
1066 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1067 NEW.rank_search := 19;
1068 NEW.rank_address := 16;
1069 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1070 NEW.rank_search := 18;
1071 NEW.rank_address := 17;
1072 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1073 NEW.rank_search := 17;
1074 NEW.rank_address := 18;
1075 ELSEIF NEW.type in ('moor') THEN
1076 NEW.rank_search := 17;
1077 NEW.rank_address := 0;
1078 ELSEIF NEW.type in ('national_park') THEN
1079 NEW.rank_search := 18;
1080 NEW.rank_address := 18;
1081 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1082 NEW.rank_search := 20;
1083 NEW.rank_address := NEW.rank_search;
1084 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1085 NEW.rank_search := 20;
1086 NEW.rank_address := 0;
1087 -- Irish townlands, tagged as place=locality and locality=townland
1088 IF (NEW.extratags -> 'locality') = 'townland' THEN
1089 NEW.rank_address := 20;
1091 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1092 NEW.rank_search := 22;
1093 NEW.rank_address := 22;
1094 ELSEIF NEW.type in ('airport','street') THEN
1095 NEW.rank_search := 26;
1096 NEW.rank_address := NEW.rank_search;
1097 ELSEIF NEW.type in ('house','building') THEN
1098 NEW.rank_search := 30;
1099 NEW.rank_address := NEW.rank_search;
1100 ELSEIF NEW.type in ('houses') THEN
1101 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1102 -- insert new point into place for each derived building
1103 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1104 NEW.rank_search := 28;
1105 NEW.rank_address := 0;
1108 ELSEIF NEW.class = 'boundary' THEN
1109 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1110 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1113 NEW.rank_search := NEW.admin_level * 2;
1114 NEW.rank_address := NEW.rank_search;
1115 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1116 NEW.rank_search := 22;
1117 NEW.rank_address := NEW.rank_search;
1118 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1119 NEW.rank_search := 18;
1120 NEW.rank_address := 0;
1121 -- any feature more than 5 square miles is probably worth indexing
1122 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1123 NEW.rank_search := 22;
1124 NEW.rank_address := NEW.rank_search;
1125 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1126 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1127 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1129 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1131 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1133 ELSEIF NEW.class = 'waterway' THEN
1134 NEW.rank_address := 17;
1135 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
1136 NEW.rank_search := 27;
1137 NEW.rank_address := NEW.rank_search;
1138 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1139 NEW.rank_search := 26;
1140 NEW.rank_address := NEW.rank_search;
1141 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1142 NEW.rank_search := 4;
1143 NEW.rank_address := NEW.rank_search;
1144 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1150 IF NEW.rank_search > 30 THEN
1151 NEW.rank_search := 30;
1154 IF NEW.rank_address > 30 THEN
1155 NEW.rank_address := 30;
1158 IF (NEW.extratags -> 'capital') = 'yes' THEN
1159 NEW.rank_search := NEW.rank_search - 1;
1162 -- a country code make no sense below rank 4 (country)
1163 IF NEW.rank_address < 4 THEN
1164 NEW.calculated_country_code := NULL;
1167 -- Block import below rank 22
1168 -- IF NEW.rank_search > 22 THEN
1172 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1174 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1176 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1177 -- Performance: We just can't handle re-indexing for country level changes
1178 IF st_area(NEW.geometry) < 1 THEN
1179 -- mark items within the geometry for re-indexing
1180 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1182 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1183 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1184 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);
1185 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1186 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);
1189 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1191 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1192 IF NEW.type='postcode' THEN
1194 ELSEIF NEW.rank_search < 16 THEN
1196 ELSEIF NEW.rank_search < 18 THEN
1198 ELSEIF NEW.rank_search < 20 THEN
1200 ELSEIF NEW.rank_search = 21 THEN
1202 ELSEIF NEW.rank_search < 24 THEN
1204 ELSEIF NEW.rank_search < 26 THEN
1205 diameter := 0.002; -- 100 to 200 meters
1206 ELSEIF NEW.rank_search < 28 THEN
1207 diameter := 0.001; -- 50 to 100 meters
1209 IF diameter > 0 THEN
1210 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1211 IF NEW.rank_search >= 26 THEN
1212 -- roads may cause reparenting for >27 rank places
1213 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1215 -- for all other places the search terms may change as well
1216 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);
1222 -- add to tables for special search
1223 -- Note: won't work on initial import because the classtype tables
1224 -- do not yet exist. It won't hurt either.
1225 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1226 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1228 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1229 USING NEW.place_id, ST_Centroid(NEW.geometry);
1233 -- IF NEW.rank_search < 26 THEN
1234 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1243 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1248 place_centroid GEOMETRY;
1250 search_maxdistance FLOAT[];
1251 search_mindistance FLOAT[];
1252 address_havelevel BOOLEAN[];
1253 -- search_scores wordscore[];
1254 -- search_scores_pos INTEGER;
1261 relation_members TEXT[];
1263 linkedplacex RECORD;
1264 search_diameter FLOAT;
1265 search_prevdiameter FLOAT;
1266 search_maxrank INTEGER;
1267 address_maxrank INTEGER;
1268 address_street_word_id INTEGER;
1269 parent_place_id_rank BIGINT;
1274 location_rank_search INTEGER;
1275 location_distance FLOAT;
1276 location_parent GEOMETRY;
1277 location_isaddress BOOLEAN;
1281 default_language TEXT;
1282 name_vector INTEGER[];
1283 nameaddress_vector INTEGER[];
1285 linked_node_id BIGINT;
1291 IF OLD.indexed_status = 100 THEN
1292 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1293 delete from placex where place_id = OLD.place_id;
1297 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1301 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1303 --RAISE WARNING '%',NEW.place_id;
1304 --RAISE WARNING '%', NEW;
1306 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1307 -- Silently do nothing
1311 IF OLD.indexed_status != 0 THEN
1312 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1314 NEW.indexed_date = now();
1316 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1317 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1321 IF OLD.indexed_status > 0 THEN
1322 result := deleteSearchName(NEW.partition, NEW.place_id);
1323 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1324 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1325 result := deleteRoad(NEW.partition, NEW.place_id);
1326 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1327 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1330 -- Speed up searches - just use the centroid of the feature
1331 -- cheaper but less acurate
1332 place_centroid := ST_PointOnSurface(NEW.geometry);
1333 NEW.centroid := null;
1335 -- reclaculate country and partition
1336 IF NEW.rank_search >= 4 THEN
1337 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1338 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1340 NEW.calculated_country_code := NULL;
1342 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1343 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1345 -- Adding ourselves to the list simplifies address calculations later
1346 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1348 -- What level are we searching from
1349 search_maxrank := NEW.rank_search;
1351 -- Thought this wasn't needed but when we add new languages to the country_name table
1352 -- we need to update the existing names
1353 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1354 default_language := get_country_language_code(NEW.calculated_country_code);
1355 IF default_language IS NOT NULL THEN
1356 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1357 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1358 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1359 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1364 -- Initialise the name vector using our name
1365 name_vector := make_keywords(NEW.name);
1366 nameaddress_vector := '{}'::int[];
1368 -- some tag combinations add a special id for search
1369 tagpairid := get_tagpair(NEW.class,NEW.type);
1370 IF tagpairid IS NOT NULL THEN
1371 name_vector := name_vector + tagpairid;
1375 address_havelevel[i] := false;
1378 NEW.importance := null;
1379 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1380 IF NEW.importance IS NULL THEN
1381 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;
1384 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1386 -- For low level elements we inherit from our parent road
1387 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1389 --RAISE WARNING 'finding street for %', NEW;
1391 -- We won't get a better centroid, besides these places are too small to care
1392 NEW.centroid := place_centroid;
1394 NEW.parent_place_id := null;
1396 -- to do that we have to find our parent road
1397 -- Copy data from linked items (points on ways, addr:street links, relations)
1398 -- Note that addr:street links can only be indexed once the street itself is indexed
1399 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1401 -- Is this node part of a relation?
1402 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1404 -- At the moment we only process one type of relation - associatedStreet
1405 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1406 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1407 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1408 --RAISE WARNING 'node in relation %',relation;
1409 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1410 and rank_search = 26 INTO NEW.parent_place_id;
1416 --RAISE WARNING 'x1';
1417 -- Is this node part of a way?
1418 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1419 --RAISE WARNING '%', way;
1420 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1422 --RAISE WARNING '%', location;
1423 -- Way IS a road then we are on it - that must be our road
1424 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1425 --RAISE WARNING 'node in way that is a street %',location;
1426 NEW.parent_place_id := location.place_id;
1429 -- Is the WAY part of a relation
1430 IF NEW.parent_place_id IS NULL THEN
1431 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1433 -- At the moment we only process one type of relation - associatedStreet
1434 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1435 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1436 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1437 --RAISE WARNING 'node in way that is in a relation %',relation;
1438 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1439 and rank_search = 26 INTO NEW.parent_place_id;
1446 -- If the way contains an explicit name of a street copy it
1447 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1448 --RAISE WARNING 'node in way that has a streetname %',location;
1449 NEW.street := location.street;
1452 -- If this way is a street interpolation line then it is probably as good as we are going to get
1453 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1454 -- Try and find a way that is close roughly parellel to this line
1455 FOR relation IN SELECT place_id FROM placex
1456 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1457 and st_geometrytype(location.geometry) in ('ST_LineString')
1458 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1459 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1460 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1462 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1463 NEW.parent_place_id := relation.place_id;
1472 --RAISE WARNING 'x2';
1474 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1475 -- Is this way part of a relation?
1476 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1478 -- At the moment we only process one type of relation - associatedStreet
1479 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1480 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1481 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1482 --RAISE WARNING 'way that is in a relation %',relation;
1483 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1484 and rank_search = 26 INTO NEW.parent_place_id;
1491 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1493 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1494 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1495 IF address_street_word_id IS NOT NULL THEN
1496 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1497 NEW.parent_place_id := location.place_id;
1502 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1503 -- Still nothing, just use the nearest road
1504 IF NEW.parent_place_id IS NULL THEN
1505 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1506 NEW.parent_place_id := location.place_id;
1511 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1513 -- If we didn't find any road fallback to standard method
1514 IF NEW.parent_place_id IS NOT NULL THEN
1516 -- Add the street to the address as zero distance to force to front of list
1517 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1518 address_havelevel[26] := true;
1520 -- Import address details from parent, reclculating distance in process
1521 -- 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
1522 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1523 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1525 -- Get the details of the parent road
1526 select * from search_name where place_id = NEW.parent_place_id INTO location;
1527 NEW.calculated_country_code := location.country_code;
1529 --RAISE WARNING '%', NEW.name;
1530 -- If there is no name it isn't searchable, don't bother to create a search record
1531 IF NEW.name is NULL THEN
1535 -- Merge address from parent
1536 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1537 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1539 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1540 -- Just be happy with inheriting from parent road only
1542 IF NEW.rank_search <= 25 THEN
1543 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1546 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);
1553 -- RAISE WARNING ' INDEXING Started:';
1554 -- RAISE WARNING ' INDEXING: %',NEW;
1556 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1558 -- see if we have any special relation members
1559 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1561 -- RAISE WARNING 'get_osm_rel_members, label';
1562 IF relation_members IS NOT NULL THEN
1563 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1565 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1566 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1568 -- If we don't already have one use this as the centre point of the geometry
1569 IF NEW.centroid IS NULL THEN
1570 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1573 -- merge in the label name, re-init word vector
1574 IF NOT linkedPlacex.name IS NULL THEN
1575 NEW.name := linkedPlacex.name || NEW.name;
1576 name_vector := make_keywords(NEW.name);
1579 -- merge in extra tags
1580 IF NOT linkedPlacex.extratags IS NULL THEN
1581 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1584 -- mark the linked place (excludes from search results)
1585 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1591 IF NEW.centroid IS NULL THEN
1593 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1595 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1596 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1598 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1599 -- But that can be fixed by explicitly setting the label in the data
1600 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1601 AND NEW.rank_address = linkedPlacex.rank_address THEN
1604 -- If we don't already have one use this as the centre point of the geometry
1605 IF NEW.centroid IS NULL THEN
1606 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1609 -- merge in the name, re-init word vector
1610 IF NOT linkedPlacex.name IS NULL THEN
1611 NEW.name := linkedPlacex.name || NEW.name;
1612 name_vector := make_keywords(NEW.name);
1615 -- merge in extra tags
1616 IF NOT linkedPlacex.extratags IS NULL THEN
1617 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1620 -- mark the linked place (excludes from search results)
1621 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1623 -- keep a note of the node id in case we need it for wikipedia in a bit
1624 linked_node_id := linkedPlacex.osm_id;
1634 -- not found one yet? how about doing a name search
1635 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1637 FOR linkedPlacex IN select placex.* from placex WHERE
1638 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1639 AND placex.rank_address = NEW.rank_address
1640 AND placex.place_id != NEW.place_id
1641 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1642 AND st_covers(NEW.geometry, placex.geometry)
1645 -- If we don't already have one use this as the centre point of the geometry
1646 IF NEW.centroid IS NULL THEN
1647 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1650 -- merge in the name, re-init word vector
1651 NEW.name := linkedPlacex.name || NEW.name;
1652 name_vector := make_keywords(NEW.name);
1654 -- merge in extra tags
1655 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1657 -- mark the linked place (excludes from search results)
1658 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1660 -- keep a note of the node id in case we need it for wikipedia in a bit
1661 linked_node_id := linkedPlacex.osm_id;
1665 IF NEW.centroid IS NOT NULL THEN
1666 place_centroid := NEW.centroid;
1669 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1670 IF NEW.importance is null THEN
1671 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1673 -- Still null? how about looking it up by the node id
1674 IF NEW.importance IS NULL THEN
1675 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;
1680 -- make sure all names are in the word table
1681 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1682 perform create_country(NEW.name, lower(NEW.country_code));
1685 NEW.parent_place_id = 0;
1686 parent_place_id_rank = 0;
1688 -- convert isin to array of tokenids
1689 isin_tokens := '{}'::int[];
1690 IF NEW.isin IS NOT NULL THEN
1691 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1692 IF array_upper(isin, 1) IS NOT NULL THEN
1693 FOR i IN 1..array_upper(isin, 1) LOOP
1694 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1695 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1696 isin_tokens := isin_tokens || address_street_word_id;
1701 IF NEW.postcode IS NOT NULL THEN
1702 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1703 IF array_upper(isin, 1) IS NOT NULL THEN
1704 FOR i IN 1..array_upper(isin, 1) LOOP
1705 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1706 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1707 isin_tokens := isin_tokens || address_street_word_id;
1713 -- for the USA we have an additional address table. Merge in zip codes from there too
1714 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1715 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1716 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1717 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1718 isin_tokens := isin_tokens || address_street_word_id;
1722 -- RAISE WARNING 'ISIN: %', isin_tokens;
1724 -- Process area matches
1725 location_rank_search := 0;
1726 location_distance := 0;
1727 location_parent := NULL;
1728 -- added ourself as address already
1729 address_havelevel[NEW.rank_address] := true;
1730 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1731 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1733 --RAISE WARNING ' AREA: %',location;
1735 IF location.rank_address != location_rank_search THEN
1736 location_rank_search := location.rank_address;
1737 location_distance := location.distance * 1.5;
1740 IF location.distance < location_distance OR NOT location.isguess THEN
1742 location_isaddress := NOT address_havelevel[location.rank_address];
1743 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1744 location_isaddress := ST_Contains(location_parent,location.centroid);
1747 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1748 -- Add it to the list of search terms
1749 IF location.rank_search > 4 THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1752 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1754 IF location_isaddress THEN
1755 address_havelevel[location.rank_address] := true;
1756 IF NOT location.isguess THEN
1757 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1761 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1763 IF location.rank_address > parent_place_id_rank THEN
1764 NEW.parent_place_id = location.place_id;
1765 parent_place_id_rank = location.rank_address;
1772 -- try using the isin value to find parent places
1773 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1774 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1775 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1776 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1778 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1780 --RAISE WARNING ' ISIN: %',location;
1782 IF location.rank_search > 4 THEN
1783 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1784 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1785 address_havelevel[location.rank_address] := true;
1787 IF location.rank_address > parent_place_id_rank THEN
1788 NEW.parent_place_id = location.place_id;
1789 parent_place_id_rank = location.rank_address;
1799 -- for long ways we should add search terms for the entire length
1800 IF st_length(NEW.geometry) > 0.05 THEN
1802 location_rank_search := 0;
1803 location_distance := 0;
1805 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1807 IF location.rank_address != location_rank_search THEN
1808 location_rank_search := location.rank_address;
1809 location_distance := location.distance * 1.5;
1812 IF location.rank_search > 4 AND location.distance < location_distance THEN
1814 -- Add it to the list of search terms
1815 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1816 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1824 -- if we have a name add this to the name search table
1825 IF NEW.name IS NOT NULL THEN
1827 IF NEW.rank_search <= 25 THEN
1828 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1831 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1832 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1835 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);
1837 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid);
1840 -- If we've not managed to pick up a better one - default centroid
1841 IF NEW.centroid IS NULL THEN
1842 NEW.centroid := place_centroid;
1852 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1858 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1860 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1861 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1862 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1863 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1865 IF OLD.rank_address < 30 THEN
1867 -- mark everything linked to this place for re-indexing
1868 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1869 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1870 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1872 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1873 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1875 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1876 b := deleteRoad(OLD.partition, OLD.place_id);
1878 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1879 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1880 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1884 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1886 IF OLD.rank_address < 26 THEN
1887 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1890 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1892 IF OLD.name is not null THEN
1893 b := deleteSearchName(OLD.partition, OLD.place_id);
1896 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1898 DELETE FROM place_addressline where place_id = OLD.place_id;
1900 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1902 -- remove from tables for special search
1903 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1904 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1906 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1909 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1917 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1923 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1925 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1926 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1927 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1932 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;
1940 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1945 existingplacex RECORD;
1946 existinggeometry GEOMETRY;
1947 existingplace_id BIGINT;
1952 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1953 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1955 IF FALSE and NEW.osm_type = 'R' THEN
1956 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;
1957 --DEBUG: RAISE WARNING '%', existingplacex;
1960 -- Just block these - lots and pointless
1961 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1964 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1968 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
1969 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1970 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1971 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1975 -- Patch in additional country names
1976 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1977 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1980 -- Have we already done this place?
1981 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;
1983 -- Get the existing place_id
1984 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;
1986 -- Handle a place changing type by removing the old data
1987 -- My generated 'place' types are causing havok because they overlap with real keys
1988 -- TODO: move them to their own special purpose key/class to avoid collisions
1989 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1990 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses');
1993 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1994 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1997 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1998 AND st_area(existing.geometry) > 0.02
1999 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2000 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2002 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2003 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2007 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2008 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2010 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry
2011 IF existingplacex.osm_type IS NULL THEN
2013 IF existing.osm_type IS NOT NULL THEN
2014 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2017 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2018 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2019 street, isin, postcode, country_code, extratags, geometry)
2020 values (NEW.osm_type
2035 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2040 -- Various ways to do the update
2042 -- Debug, what's changed?
2044 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2045 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2047 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2048 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2050 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2051 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2053 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2054 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2056 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2057 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2059 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2060 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2064 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2065 IF existing.geometry::text != NEW.geometry::text
2066 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2067 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2070 -- Get the version of the geometry actually used (in placex table)
2071 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;
2073 -- Performance limit
2074 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2076 -- 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
2077 update placex set indexed_status = 2 where indexed_status = 0 and
2078 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2079 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2080 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2082 update placex set indexed_status = 2 where indexed_status = 0 and
2083 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2084 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2085 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2091 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2092 IF FALSE AND existingplacex.rank_search < 26
2093 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2094 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2095 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2096 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2097 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2098 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2101 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2103 IF st_area(NEW.geometry) < 0.5 THEN
2104 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2105 and placex.place_id = place_addressline.place_id and indexed_status = 0
2106 and (rank_search < 28 or name is not null);
2113 -- Anything else has changed - reindex the lot
2114 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2115 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2116 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2117 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2118 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2119 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2121 -- performance, can't take the load of re-indexing a whole country / huge area
2122 IF st_area(NEW.geometry) < 0.5 THEN
2123 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2124 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2131 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2132 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2133 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2134 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2135 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2136 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2137 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2138 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2139 OR existing.geometry::text != NEW.geometry::text
2144 housenumber = NEW.housenumber,
2145 street = NEW.street,
2147 postcode = NEW.postcode,
2148 country_code = NEW.country_code,
2149 extratags = NEW.extratags,
2150 geometry = NEW.geometry
2151 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2155 housenumber = NEW.housenumber,
2156 street = NEW.street,
2158 postcode = NEW.postcode,
2159 country_code = NEW.country_code,
2160 parent_place_id = null,
2161 extratags = NEW.extratags,
2163 geometry = NEW.geometry
2164 where place_id = existingplacex.place_id;
2168 -- Abort the add (we modified the existing place instead)
2172 $$ LANGUAGE plpgsql;
2174 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2181 IF name is null THEN
2185 search := languagepref;
2187 FOR j IN 1..array_upper(search, 1) LOOP
2188 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2189 return trim(name->search[j]);
2193 -- anything will do as a fallback - just take the first name type thing there is
2194 search := avals(name);
2198 LANGUAGE plpgsql IMMUTABLE;
2200 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2203 searchnodes INTEGER[];
2208 searchnodes := '{}';
2209 FOR j IN 1..array_upper(way_ids, 1) LOOP
2211 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2213 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2214 searchnodes := searchnodes || location.nodes;
2219 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2222 LANGUAGE plpgsql IMMUTABLE;
2224 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2235 search := ARRAY['ref'];
2238 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2241 select rank_address,name,distance,length(name::text) as namelength
2242 from place_addressline join placex on (address_place_id = placex.place_id)
2243 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2244 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2246 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2247 FOR j IN 1..array_upper(search, 1) LOOP
2248 FOR k IN 1..array_upper(location.name, 1) LOOP
2249 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
2250 result[(100 - location.rank_address)] := trim(location.name[k].value);
2251 found := location.rank_address;
2258 RETURN array_to_string(result,', ');
2263 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2275 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2276 currresult := trim(get_name_by_language(location.name, languagepref));
2277 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2278 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2279 prevresult := currresult;
2283 RETURN array_to_string(result,', ');
2288 DROP TYPE addressline CASCADE;
2289 create type addressline as (
2296 admin_level INTEGER,
2299 rank_address INTEGER,
2303 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2306 for_place_id BIGINT;
2311 countrylocation RECORD;
2312 searchcountrycode varchar(2);
2313 searchhousenumber TEXT;
2314 searchhousename HSTORE;
2315 searchrankaddress INTEGER;
2316 searchpostcode TEXT;
2323 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2324 WHERE place_id = in_place_id
2325 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2327 IF for_place_id IS NULL THEN
2328 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2329 WHERE place_id = in_place_id
2330 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2333 IF for_place_id IS NULL THEN
2334 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2335 WHERE place_id = in_place_id and rank_address = 30
2336 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2339 IF for_place_id IS NULL THEN
2340 for_place_id := in_place_id;
2341 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2342 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2345 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2348 hadcountry := false;
2350 select placex.place_id, osm_type, osm_id,
2351 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2352 class, type, admin_level, true as fromarea, true as isaddress,
2353 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2354 0 as distance, calculated_country_code
2356 where place_id = for_place_id
2358 --RAISE WARNING '%',location;
2359 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2360 searchcountrycode := location.calculated_country_code;
2362 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2363 location.isaddress := FALSE;
2365 IF location.rank_address = 4 AND location.isaddress THEN
2368 IF location.rank_address < 4 AND NOT hadcountry THEN
2369 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2370 IF countryname IS NOT NULL THEN
2371 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2372 RETURN NEXT countrylocation;
2375 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2376 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2377 location.distance)::addressline;
2378 RETURN NEXT countrylocation;
2379 found := location.rank_address;
2383 select placex.place_id, osm_type, osm_id,
2384 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2385 class, type, admin_level, fromarea, isaddress,
2386 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,
2387 distance,calculated_country_code
2388 from place_addressline join placex on (address_place_id = placex.place_id)
2389 where place_addressline.place_id = for_place_id
2390 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2391 and address_place_id != for_place_id
2392 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2393 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2395 --RAISE WARNING '%',location;
2396 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2397 searchcountrycode := location.calculated_country_code;
2399 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2400 location.isaddress := FALSE;
2402 IF location.rank_address = 4 AND location.isaddress THEN
2405 IF location.rank_address < 4 AND NOT hadcountry THEN
2406 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2407 IF countryname IS NOT NULL THEN
2408 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2409 RETURN NEXT countrylocation;
2412 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2413 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2414 location.distance)::addressline;
2415 RETURN NEXT countrylocation;
2416 found := location.rank_address;
2420 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2421 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2422 IF countryname IS NOT NULL THEN
2423 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2424 RETURN NEXT location;
2428 IF searchcountrycode IS NOT NULL THEN
2429 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2430 RETURN NEXT location;
2433 IF searchhousename IS NOT NULL THEN
2434 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2435 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2436 RETURN NEXT location;
2439 IF searchhousenumber IS NOT NULL THEN
2440 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2441 RETURN NEXT location;
2444 IF searchpostcode IS NOT NULL THEN
2445 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2446 RETURN NEXT location;
2454 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2457 result place_boundingbox;
2458 numfeatures integer;
2460 select * from place_boundingbox into result where place_id = search_place_id;
2461 IF result.place_id IS NULL THEN
2462 -- remove isaddress = true because if there is a matching polygon it always wins
2463 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2464 insert into place_boundingbox select place_id,
2465 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2466 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2467 numfeatures, ST_Area(geometry),
2468 geometry as area from location_area where place_id = search_place_id;
2469 select * from place_boundingbox into result where place_id = search_place_id;
2471 IF result.place_id IS NULL THEN
2473 insert into place_boundingbox select address_place_id,
2474 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2475 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2476 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2477 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2478 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)
2479 where address_place_id = search_place_id
2480 -- and (isaddress = true OR place_id = search_place_id)
2481 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2482 group by address_place_id limit 1;
2483 select * from place_boundingbox into result where place_id = search_place_id;
2490 -- don't do the operation if it would be slow
2491 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2494 result place_boundingbox;
2495 numfeatures integer;
2498 select * from place_boundingbox into result where place_id = search_place_id;
2499 IF result IS NULL AND rank > 14 THEN
2500 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2501 insert into place_boundingbox select place_id,
2502 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2503 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2504 numfeatures, ST_Area(geometry),
2505 geometry as area from location_area where place_id = search_place_id;
2506 select * from place_boundingbox into result where place_id = search_place_id;
2508 IF result IS NULL THEN
2509 select rank_search from placex where place_id = search_place_id into rank;
2512 insert into place_boundingbox select address_place_id,
2513 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2514 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2515 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2516 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2517 from place_addressline join placex using (place_id)
2518 where address_place_id = search_place_id
2519 and (isaddress = true OR place_id = search_place_id)
2520 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2521 group by address_place_id limit 1;
2522 select * from place_boundingbox into result where place_id = search_place_id;
2530 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2533 result place_boundingbox;
2534 numfeatures integer;
2538 housenumber = place.housenumber,
2539 street = place.street,
2541 postcode = place.postcode,
2542 country_code = place.country_code,
2543 parent_place_id = null
2545 where placex.place_id = search_place_id
2546 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2547 and place.class = placex.class and place.type = placex.type;
2548 update placex set indexed_status = 2 where place_id = search_place_id;
2549 update placex set indexed_status = 0 where place_id = search_place_id;
2555 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2561 ELSEIF rank < 4 THEN
2563 ELSEIF rank < 8 THEN
2565 ELSEIF rank < 12 THEN
2567 ELSEIF rank < 16 THEN
2569 ELSEIF rank = 16 THEN
2571 ELSEIF rank = 17 THEN
2572 RETURN 'Town / Island';
2573 ELSEIF rank = 18 THEN
2574 RETURN 'Village / Hamlet';
2575 ELSEIF rank = 20 THEN
2577 ELSEIF rank = 21 THEN
2578 RETURN 'Postcode Area';
2579 ELSEIF rank = 22 THEN
2580 RETURN 'Croft / Farm / Locality / Islet';
2581 ELSEIF rank = 23 THEN
2582 RETURN 'Postcode Area';
2583 ELSEIF rank = 25 THEN
2584 RETURN 'Postcode Point';
2585 ELSEIF rank = 26 THEN
2586 RETURN 'Street / Major Landmark';
2587 ELSEIF rank = 27 THEN
2588 RETURN 'Minory Street / Path';
2589 ELSEIF rank = 28 THEN
2590 RETURN 'House / Building';
2592 RETURN 'Other: '||rank;
2599 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2605 ELSEIF rank < 2 THEN
2607 ELSEIF rank < 4 THEN
2609 ELSEIF rank = 5 THEN
2611 ELSEIF rank < 8 THEN
2613 ELSEIF rank < 12 THEN
2615 ELSEIF rank < 16 THEN
2617 ELSEIF rank = 16 THEN
2619 ELSEIF rank = 17 THEN
2620 RETURN 'Town / Village / Hamlet';
2621 ELSEIF rank = 20 THEN
2623 ELSEIF rank = 21 THEN
2624 RETURN 'Postcode Area';
2625 ELSEIF rank = 22 THEN
2626 RETURN 'Croft / Farm / Locality / Islet';
2627 ELSEIF rank = 23 THEN
2628 RETURN 'Postcode Area';
2629 ELSEIF rank = 25 THEN
2630 RETURN 'Postcode Point';
2631 ELSEIF rank = 26 THEN
2632 RETURN 'Street / Major Landmark';
2633 ELSEIF rank = 27 THEN
2634 RETURN 'Minory Street / Path';
2635 ELSEIF rank = 28 THEN
2636 RETURN 'House / Building';
2638 RETURN 'Other: '||rank;
2645 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2652 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2653 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2660 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2668 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2670 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2671 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2673 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2681 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2682 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2687 place_centroid GEOMETRY;
2688 out_partition INTEGER;
2689 out_parent_place_id BIGINT;
2691 address_street_word_id INTEGER;
2696 place_centroid := ST_Centroid(pointgeo);
2697 out_partition := get_partition(place_centroid, in_countrycode);
2698 out_parent_place_id := null;
2700 address_street_word_id := get_name_id(make_standard_name(in_street));
2701 IF address_street_word_id IS NOT NULL THEN
2702 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2703 out_parent_place_id := location.place_id;
2707 IF out_parent_place_id IS NULL THEN
2708 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2709 out_parent_place_id := location.place_id;
2713 out_postcode := in_postcode;
2714 IF out_postcode IS NULL THEN
2715 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2717 IF out_postcode IS NULL THEN
2718 out_postcode := getNearestPostcode(out_partition, place_centroid);
2722 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2723 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2724 newpoints := newpoints + 1;
2731 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2738 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2739 IF members[i+1] = member THEN
2740 result := result || members[i];
2749 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2755 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2756 IF members[i+1] = ANY(memberLabels) THEN
2757 RETURN NEXT members[i];
2766 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2767 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2769 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2770 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
2771 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2772 ), '') AS bytea), 'UTF8');
2774 LANGUAGE SQL IMMUTABLE STRICT;
2776 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2780 RETURN decode_url_part(p);
2782 WHEN others THEN return null;
2785 LANGUAGE plpgsql IMMUTABLE;
2787 DROP TYPE wikipedia_article_match CASCADE;
2788 create type wikipedia_article_match as (
2794 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2800 wiki_article_title TEXT;
2801 wiki_article_language TEXT;
2802 result wikipedia_article_match;
2804 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'];
2806 WHILE langs[i] IS NOT NULL LOOP
2807 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2808 IF wiki_article is not null THEN
2809 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2810 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2811 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2812 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2813 wiki_article := replace(wiki_article,' ','_');
2814 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2815 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2816 wiki_article_title := trim(wiki_article);
2817 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;
2819 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2822 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2823 from wikipedia_article
2824 where language = wiki_article_language and
2825 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2827 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2828 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2829 where wikipedia_redirect.language = wiki_article_language and
2830 (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'\\',''))
2831 order by importance desc limit 1 INTO result;
2833 IF result.language is not null THEN
2844 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2845 RETURNS SETOF GEOMETRY
2859 remainingdepth INTEGER;
2864 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2866 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2867 RETURN NEXT geometry;
2871 remainingdepth := maxdepth - 1;
2872 area := ST_AREA(geometry);
2873 IF remainingdepth < 1 OR area < maxarea THEN
2874 RETURN NEXT geometry;
2878 xmin := st_xmin(geometry);
2879 xmax := st_xmax(geometry);
2880 ymin := st_ymin(geometry);
2881 ymax := st_ymax(geometry);
2882 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2884 -- if the geometry completely covers the box don't bother to slice any more
2885 IF ST_AREA(secbox) = area THEN
2886 RETURN NEXT geometry;
2890 xmid := (xmin+xmax)/2;
2891 ymid := (ymin+ymax)/2;
2894 FOR seg IN 1..4 LOOP
2897 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2900 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2903 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2906 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2909 IF st_intersects(geometry, secbox) THEN
2910 secgeo := st_intersection(geometry, secbox);
2911 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2912 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2913 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2915 RETURN NEXT geo.geom;
2927 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2928 RETURNS SETOF GEOMETRY
2933 -- 10000000000 is ~~ 1x1 degree
2934 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2935 RETURN NEXT geo.geom;
2943 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2947 osmtype character(1);
2951 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2952 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2953 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2954 -- force delete from place/placex by making it a very small geometry
2955 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;
2956 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2963 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2971 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2972 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2973 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2974 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2975 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2976 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null);
2977 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2978 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null);
2984 ELSEIF rank < 18 THEN
2986 ELSEIF rank < 20 THEN
2988 ELSEIF rank = 21 THEN
2990 ELSEIF rank < 24 THEN
2992 ELSEIF rank < 26 THEN
2993 diameter := 0.002; -- 100 to 200 meters
2994 ELSEIF rank < 28 THEN
2995 diameter := 0.001; -- 50 to 100 meters
2997 IF diameter > 0 THEN
2998 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);