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 (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 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
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
55 NEWgeometry := ST_PointOnSurface(place);
56 -- 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
57 -- NEWgeometry := ST_buffer(NEWgeometry,0);
58 -- 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
62 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
68 AS '{modulepath}/nominatim.so', 'transliteration'
69 LANGUAGE c IMMUTABLE STRICT;
71 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
72 AS '{modulepath}/nominatim.so', 'gettokenstring'
73 LANGUAGE c IMMUTABLE STRICT;
75 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
80 o := gettokenstring(transliteration(name));
81 RETURN trim(substr(o,1,length(o)));
84 LANGUAGE 'plpgsql' IMMUTABLE;
86 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
91 return_word_id INTEGER;
93 lookup_token := trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 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);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
145 return_word_id INTEGER;
147 lookup_token := ' '||trim(lookup_word);
148 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
149 IF return_word_id IS NULL THEN
150 return_word_id := nextval('seq_word');
151 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
153 RETURN return_word_id;
158 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
163 return_word_id INTEGER;
165 lookup_token := lookup_class||'='||lookup_type;
166 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
167 IF return_word_id IS NULL THEN
168 return_word_id := nextval('seq_word');
169 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
171 RETURN return_word_id;
176 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
181 return_word_id INTEGER;
183 lookup_token := lookup_class||'='||lookup_type;
184 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
185 RETURN return_word_id;
190 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
195 return_word_id INTEGER;
197 lookup_token := ' '||trim(lookup_word);
198 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;
199 IF return_word_id IS NULL THEN
200 return_word_id := nextval('seq_word');
201 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
203 RETURN return_word_id;
208 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
213 nospace_lookup_token TEXT;
214 return_word_id INTEGER;
216 lookup_token := ' '||trim(lookup_word);
217 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
218 IF return_word_id IS NULL THEN
219 return_word_id := nextval('seq_word');
220 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);
221 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
222 -- IF ' '||nospace_lookup_token != lookup_token THEN
223 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
226 RETURN return_word_id;
231 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
236 RETURN getorcreate_name_id(lookup_word, '');
241 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
246 return_word_id INTEGER;
248 lookup_token := trim(lookup_word);
249 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
250 RETURN return_word_id;
253 LANGUAGE plpgsql IMMUTABLE;
255 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
260 return_word_id INTEGER;
262 lookup_token := ' '||trim(lookup_word);
263 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
264 RETURN return_word_id;
267 LANGUAGE plpgsql IMMUTABLE;
269 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
276 IF array_upper(a, 1) IS NULL THEN
279 IF array_upper(b, 1) IS NULL THEN
283 FOR i IN 1..array_upper(b, 1) LOOP
284 IF NOT (ARRAY[b[i]] <@ r) THEN
291 LANGUAGE plpgsql IMMUTABLE;
293 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
303 result := '{}'::INTEGER[];
305 FOR item IN SELECT (each(src)).* LOOP
307 s := make_standard_name(item.value);
309 w := getorcreate_name_id(s, item.value);
311 IF not(ARRAY[w] <@ result) THEN
312 result := result || w;
315 words := string_to_array(s, ' ');
316 IF array_upper(words, 1) IS NOT NULL THEN
317 FOR j IN 1..array_upper(words, 1) LOOP
318 IF (words[j] != '') THEN
319 w = getorcreate_word_id(words[j]);
320 IF NOT (ARRAY[w] <@ result) THEN
321 result := result || w;
327 words := regexp_split_to_array(item.value, E'[,;()]');
328 IF array_upper(words, 1) != 1 THEN
329 FOR j IN 1..array_upper(words, 1) LOOP
330 s := make_standard_name(words[j]);
332 w := getorcreate_word_id(s);
333 IF NOT (ARRAY[w] <@ result) THEN
334 result := result || w;
340 s := regexp_replace(item.value, '市$', '');
341 IF s != item.value THEN
342 s := make_standard_name(s);
344 w := getorcreate_name_id(s, item.value);
345 IF NOT (ARRAY[w] <@ result) THEN
346 result := result || w;
356 LANGUAGE plpgsql IMMUTABLE;
358 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
368 result := '{}'::INTEGER[];
370 s := make_standard_name(src);
371 w := getorcreate_name_id(s, src);
373 IF NOT (ARRAY[w] <@ result) THEN
374 result := result || w;
377 words := string_to_array(s, ' ');
378 IF array_upper(words, 1) IS NOT NULL THEN
379 FOR j IN 1..array_upper(words, 1) LOOP
380 IF (words[j] != '') THEN
381 w = getorcreate_word_id(words[j]);
382 IF NOT (ARRAY[w] <@ result) THEN
383 result := result || w;
389 words := regexp_split_to_array(src, E'[,;()]');
390 IF array_upper(words, 1) != 1 THEN
391 FOR j IN 1..array_upper(words, 1) LOOP
392 s := make_standard_name(words[j]);
394 w := getorcreate_word_id(s);
395 IF NOT (ARRAY[w] <@ result) THEN
396 result := result || w;
402 s := regexp_replace(src, '市$', '');
404 s := make_standard_name(s);
406 w := getorcreate_name_id(s, src);
407 IF NOT (ARRAY[w] <@ result) THEN
408 result := result || w;
416 LANGUAGE plpgsql IMMUTABLE;
418 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
425 IF (wordscores is null OR words is null) THEN
430 FOR idxword in 1 .. array_upper(words, 1) LOOP
431 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
432 IF wordscores[idxscores].word = words[idxword] THEN
433 result := result + wordscores[idxscores].score;
441 LANGUAGE plpgsql IMMUTABLE;
443 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
446 place_centre GEOMETRY;
449 place_centre := ST_PointOnSurface(place);
451 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
453 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
455 -- Try for OSM fallback data
456 -- The order is to deal with places like HongKong that are 'states' within another polygon
457 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
459 RETURN nearcountry.country_code;
462 -- Try for a OSM polygon
463 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
465 RETURN nearcountry.country_code;
468 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
470 -- Natural earth data
471 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
473 RETURN nearcountry.country_code;
476 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
479 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
481 RETURN nearcountry.country_code;
484 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
486 -- Natural earth data
487 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
489 RETURN nearcountry.country_code;
492 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
493 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
495 -- RETURN nearcountry.country_code;
498 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
500 -- Still not in a country - try nearest within ~12 miles of a country
501 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
502 -- order by st_distance(geometry, place) limit 1
504 -- RETURN nearcountry.country_code;
510 LANGUAGE plpgsql IMMUTABLE;
512 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
517 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
519 RETURN nearcountry.country_code;
521 RETURN get_country_code(place);
524 LANGUAGE plpgsql IMMUTABLE;
526 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
531 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
533 RETURN lower(nearcountry.country_default_language_code);
538 LANGUAGE plpgsql IMMUTABLE;
540 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
543 place_centre GEOMETRY;
546 FOR nearcountry IN select partition from country_name where country_code = in_country_code
548 RETURN nearcountry.partition;
553 LANGUAGE plpgsql IMMUTABLE;
555 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
559 DELETE FROM location_area where place_id = OLD_place_id;
560 -- TODO:location_area
566 CREATE OR REPLACE FUNCTION add_location(
568 country_code varchar(2),
572 rank_address INTEGER,
587 IF rank_search > 25 THEN
588 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
591 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
593 x := deleteLocationArea(partition, place_id);
596 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
599 centroid := ST_Centroid(geometry);
601 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
602 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
605 ELSEIF rank_search < 26 THEN
608 IF rank_address = 0 THEN
610 ELSEIF rank_search <= 14 THEN
612 ELSEIF rank_search <= 15 THEN
614 ELSEIF rank_search <= 16 THEN
616 ELSEIF rank_search <= 17 THEN
618 ELSEIF rank_search <= 21 THEN
620 ELSEIF rank_search = 25 THEN
624 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
626 secgeo := ST_Buffer(geometry, diameter);
627 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
632 secgeo := ST_Buffer(geometry, 0.0002);
633 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
636 secgeo := ST_Buffer(geometry, 0.001);
637 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
646 CREATE OR REPLACE FUNCTION update_location(
649 place_country_code varchar(2),
652 rank_address INTEGER,
660 b := deleteLocationArea(partition, place_id);
661 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
662 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
667 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
678 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
679 FOR childplace IN select * from search_name,place_addressline
680 where address_place_id = parent_place_id
681 and search_name.place_id = place_addressline.place_id
683 delete from search_name where place_id = childplace.place_id;
684 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
685 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
687 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
688 childplace.name_vector := childplace.name_vector || to_add;
690 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
691 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
692 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
700 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
703 newkeywords INTEGER[];
704 addedkeywords INTEGER[];
705 removedkeywords INTEGER[];
709 newkeywords := make_keywords(name);
710 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
711 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
712 where place_id = OLD_place_id into addedkeywords, removedkeywords;
714 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
716 IF #removedkeywords > 0 THEN
717 -- abort due to tokens removed
721 IF #addedkeywords > 0 THEN
722 -- short circuit - no changes
726 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
727 RETURN search_name_add_words(OLD_place_id, addedkeywords);
733 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
745 orginalstartnumber INTEGER;
746 originalnumberrange INTEGER;
749 search_place_id BIGINT;
752 havefirstpoint BOOLEAN;
756 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
758 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
759 select nodes from planet_osm_ways where id = wayid INTO waynodes;
760 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
761 IF array_upper(waynodes, 1) IS NOT NULL THEN
763 havefirstpoint := false;
765 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
767 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
768 IF search_place_id IS NULL THEN
769 -- null record of right type
770 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
771 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
772 IF nextnode.geometry IS NULL THEN
773 -- we don't have any information about this point, most likely
774 -- because an excerpt was updated and the node never imported
775 -- because the interpolation is outside the region of the excerpt.
780 select * from placex where place_id = search_place_id INTO nextnode;
783 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
785 IF havefirstpoint THEN
787 -- add point to the line string
788 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
789 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
791 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
793 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
795 IF startnumber != endnumber THEN
797 linestr := linestr || ')';
798 --RAISE WARNING 'linestr %',linestr;
799 linegeo := ST_GeomFromText(linestr,4326);
800 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
801 IF (startnumber > endnumber) THEN
802 housenum := endnumber;
803 endnumber := startnumber;
804 startnumber := housenum;
805 linegeo := ST_Reverse(linegeo);
807 orginalstartnumber := startnumber;
808 originalnumberrange := endnumber - startnumber;
810 -- Too much broken data worldwide for this test to be worth using
811 -- IF originalnumberrange > 500 THEN
812 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
815 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
816 startnumber := startnumber + 1;
819 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
820 startnumber := startnumber + 2;
822 ELSE -- everything else assumed to be 'all'
823 startnumber := startnumber + 1;
827 endnumber := endnumber - 1;
828 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
829 FOR housenum IN startnumber..endnumber BY stepsize LOOP
830 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
831 -- ideally postcodes should move up to the way
832 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
833 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
834 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
835 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));
836 newpoints := newpoints + 1;
837 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
840 havefirstpoint := false;
844 IF NOT havefirstpoint THEN
845 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
846 IF startnumber IS NOT NULL AND startnumber > 0 THEN
847 havefirstpoint := true;
848 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
849 prevnode := nextnode;
851 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
857 --RAISE WARNING 'interpolation points % ',newpoints;
864 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
870 country_code VARCHAR(2);
871 default_language VARCHAR(10);
875 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
878 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
879 -- RAISE WARNING 'bad highway %',NEW.osm_id;
882 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
883 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
887 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
888 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
889 RAISE WARNING 'invalid geometry %',NEW.osm_id;
893 IF NEW.osm_type = 'R' THEN
894 -- invalid multipolygons can crash postgis, don't even bother to try!
897 NEW.geometry := ST_buffer(NEW.geometry,0);
898 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
899 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
904 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
906 NEW.place_id := nextval('seq_place');
907 NEW.indexed_status := 1; --STATUS_NEW
909 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
911 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
912 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
914 -- copy 'name' to or from the default language (if there is a default language)
915 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
916 default_language := get_country_language_code(NEW.calculated_country_code);
917 IF default_language IS NOT NULL THEN
918 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
919 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
920 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
921 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
926 IF NEW.admin_level > 15 THEN
927 NEW.admin_level := 15;
930 IF NEW.housenumber IS NOT NULL THEN
931 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
934 IF NEW.osm_type = 'X' THEN
935 -- E'X'ternal records should already be in the right format so do nothing
937 NEW.rank_search := 30;
938 NEW.rank_address := NEW.rank_search;
940 -- By doing in postgres we have the country available to us - currently only used for postcode
941 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
943 IF NEW.postcode IS NULL THEN
944 -- most likely just a part of a multipolygon postcode boundary, throw it away
948 NEW.name := 'ref'=>NEW.postcode;
950 IF NEW.calculated_country_code = 'gb' THEN
952 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
953 NEW.rank_search := 25;
954 NEW.rank_address := 5;
955 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
956 NEW.rank_search := 23;
957 NEW.rank_address := 5;
958 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
959 NEW.rank_search := 21;
960 NEW.rank_address := 5;
963 ELSEIF NEW.calculated_country_code = 'de' THEN
965 IF NEW.postcode ~ '^([0-9]{5})$' THEN
966 NEW.rank_search := 21;
967 NEW.rank_address := 11;
971 -- Guess at the postcode format and coverage (!)
972 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
973 NEW.rank_search := 21;
974 NEW.rank_address := 11;
976 -- Does it look splitable into and area and local code?
977 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
979 IF postcode IS NOT NULL THEN
980 NEW.rank_search := 25;
981 NEW.rank_address := 11;
982 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
983 NEW.rank_search := 21;
984 NEW.rank_address := 11;
989 ELSEIF NEW.class = 'place' THEN
990 IF NEW.type in ('continent') THEN
991 NEW.rank_search := 2;
992 NEW.rank_address := NEW.rank_search;
993 NEW.calculated_country_code := NULL;
994 ELSEIF NEW.type in ('sea') THEN
995 NEW.rank_search := 2;
996 NEW.rank_address := 0;
997 NEW.calculated_country_code := NULL;
998 ELSEIF NEW.type in ('country') THEN
999 NEW.rank_search := 4;
1000 NEW.rank_address := NEW.rank_search;
1001 ELSEIF NEW.type in ('state') THEN
1002 NEW.rank_search := 8;
1003 NEW.rank_address := NEW.rank_search;
1004 ELSEIF NEW.type in ('region') THEN
1005 NEW.rank_search := 18; -- dropped from previous value of 10
1006 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1007 ELSEIF NEW.type in ('county') THEN
1008 NEW.rank_search := 12;
1009 NEW.rank_address := NEW.rank_search;
1010 ELSEIF NEW.type in ('city') THEN
1011 NEW.rank_search := 16;
1012 NEW.rank_address := NEW.rank_search;
1013 ELSEIF NEW.type in ('island') THEN
1014 NEW.rank_search := 17;
1015 NEW.rank_address := 0;
1016 ELSEIF NEW.type in ('town') THEN
1017 NEW.rank_search := 18;
1018 NEW.rank_address := 16;
1019 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1020 NEW.rank_search := 19;
1021 NEW.rank_address := 16;
1022 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1023 NEW.rank_search := 18;
1024 NEW.rank_address := 17;
1025 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1026 NEW.rank_search := 17;
1027 NEW.rank_address := 18;
1028 ELSEIF NEW.type in ('moor') THEN
1029 NEW.rank_search := 17;
1030 NEW.rank_address := 0;
1031 ELSEIF NEW.type in ('national_park') THEN
1032 NEW.rank_search := 18;
1033 NEW.rank_address := 18;
1034 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1035 NEW.rank_search := 20;
1036 NEW.rank_address := NEW.rank_search;
1037 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1038 NEW.rank_search := 20;
1039 NEW.rank_address := 0;
1040 -- Irish townlands, tagged as place=locality and locality=townland
1041 IF (NEW.extratags -> 'locality') = 'townland' THEN
1042 NEW.rank_address := 20;
1044 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1045 NEW.rank_search := 22;
1046 NEW.rank_address := 22;
1047 ELSEIF NEW.type in ('airport','street') THEN
1048 NEW.rank_search := 26;
1049 NEW.rank_address := NEW.rank_search;
1050 ELSEIF NEW.type in ('house','building') THEN
1051 NEW.rank_search := 30;
1052 NEW.rank_address := NEW.rank_search;
1053 ELSEIF NEW.type in ('houses') THEN
1054 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1055 -- insert new point into place for each derived building
1056 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1057 NEW.rank_search := 28;
1058 NEW.rank_address := 0;
1061 ELSEIF NEW.class = 'boundary' THEN
1062 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1063 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1066 NEW.rank_search := NEW.admin_level * 2;
1067 NEW.rank_address := NEW.rank_search;
1068 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1069 NEW.rank_search := 22;
1070 NEW.rank_address := NEW.rank_search;
1071 -- any feature more than 5 square miles is probably worth indexing
1072 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1073 NEW.rank_search := 22;
1074 NEW.rank_address := NEW.rank_search;
1075 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1076 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1077 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1079 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1081 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1083 ELSEIF NEW.class = 'waterway' THEN
1084 NEW.rank_address := 17;
1085 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
1086 NEW.rank_search := 27;
1087 NEW.rank_address := NEW.rank_search;
1088 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1089 NEW.rank_search := 26;
1090 NEW.rank_address := NEW.rank_search;
1091 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1092 NEW.rank_search := 4;
1093 NEW.rank_address := NEW.rank_search;
1094 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1096 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1097 NEW.rank_search := 18;
1098 NEW.rank_address := 0;
1103 IF NEW.rank_search > 30 THEN
1104 NEW.rank_search := 30;
1107 IF NEW.rank_address > 30 THEN
1108 NEW.rank_address := 30;
1111 IF (NEW.extratags -> 'capital') = 'yes' THEN
1112 NEW.rank_search := NEW.rank_search - 1;
1115 -- a country code make no sense below rank 4 (country)
1116 IF NEW.rank_address < 4 THEN
1117 NEW.calculated_country_code := NULL;
1120 -- Block import below rank 22
1121 -- IF NEW.rank_search > 22 THEN
1125 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1127 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1129 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1130 -- Performance: We just can't handle re-indexing for country level changes
1131 IF st_area(NEW.geometry) < 1 THEN
1132 -- mark items within the geometry for re-indexing
1133 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1135 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1136 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1137 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);
1138 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1139 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);
1142 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1144 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1145 IF NEW.type='postcode' THEN
1147 ELSEIF NEW.rank_search < 16 THEN
1149 ELSEIF NEW.rank_search < 18 THEN
1151 ELSEIF NEW.rank_search < 20 THEN
1153 ELSEIF NEW.rank_search = 21 THEN
1155 ELSEIF NEW.rank_search < 24 THEN
1157 ELSEIF NEW.rank_search < 26 THEN
1158 diameter := 0.002; -- 100 to 200 meters
1159 ELSEIF NEW.rank_search < 28 THEN
1160 diameter := 0.001; -- 50 to 100 meters
1162 IF diameter > 0 THEN
1163 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1164 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);
1169 -- add to tables for special search
1170 -- Note: won't work on initial import because the classtype tables
1171 -- do not yet exist. It won't hurt either.
1172 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1173 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1175 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1176 USING NEW.place_id, ST_Centroid(NEW.geometry);
1180 -- IF NEW.rank_search < 26 THEN
1181 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1190 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1195 place_centroid GEOMETRY;
1197 search_maxdistance FLOAT[];
1198 search_mindistance FLOAT[];
1199 address_havelevel BOOLEAN[];
1200 -- search_scores wordscore[];
1201 -- search_scores_pos INTEGER;
1208 relation_members TEXT[];
1210 linkedplacex RECORD;
1211 search_diameter FLOAT;
1212 search_prevdiameter FLOAT;
1213 search_maxrank INTEGER;
1214 address_maxrank INTEGER;
1215 address_street_word_id INTEGER;
1216 parent_place_id_rank BIGINT;
1221 location_rank_search INTEGER;
1222 location_distance FLOAT;
1223 location_parent GEOMETRY;
1224 location_isaddress BOOLEAN;
1228 default_language TEXT;
1229 name_vector INTEGER[];
1230 nameaddress_vector INTEGER[];
1232 linked_node_id BIGINT;
1237 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1241 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1243 --RAISE WARNING '%',NEW.place_id;
1244 --RAISE WARNING '%', NEW;
1246 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1247 -- Silently do nothing
1252 IF OLD.indexed_status = 100 THEN
1253 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1254 delete from placex where place_id = OLD.place_id;
1258 IF OLD.indexed_status != 0 THEN
1259 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1261 NEW.indexed_date = now();
1263 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1264 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1268 IF OLD.indexed_status > 0 THEN
1269 result := deleteSearchName(NEW.partition, NEW.place_id);
1270 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1271 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1272 result := deleteRoad(NEW.partition, NEW.place_id);
1273 result := deleteLocationArea(NEW.partition, NEW.place_id);
1274 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1277 -- Speed up searches - just use the centroid of the feature
1278 -- cheaper but less acurate
1279 place_centroid := ST_PointOnSurface(NEW.geometry);
1280 NEW.centroid := null;
1282 -- reclaculate country and partition
1283 IF NEW.rank_search >= 4 THEN
1284 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1285 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1287 NEW.calculated_country_code := NULL;
1289 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1290 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1292 -- Adding ourselves to the list simplifies address calculations later
1293 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1295 -- What level are we searching from
1296 search_maxrank := NEW.rank_search;
1298 -- Thought this wasn't needed but when we add new languages to the country_name table
1299 -- we need to update the existing names
1300 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1301 default_language := get_country_language_code(NEW.calculated_country_code);
1302 IF default_language IS NOT NULL THEN
1303 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1304 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1305 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1306 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1311 -- Initialise the name vector using our name
1312 name_vector := make_keywords(NEW.name);
1313 nameaddress_vector := '{}'::int[];
1315 -- some tag combinations add a special id for search
1316 tagpairid := get_tagpair(NEW.class,NEW.type);
1317 IF tagpairid IS NOT NULL THEN
1318 name_vector := name_vector + tagpairid;
1322 address_havelevel[i] := false;
1325 NEW.importance := null;
1326 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1327 IF NEW.importance IS NULL THEN
1328 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;
1331 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1333 -- For low level elements we inherit from our parent road
1334 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1336 --RAISE WARNING 'finding street for %', NEW;
1338 NEW.parent_place_id := null;
1340 -- to do that we have to find our parent road
1341 -- Copy data from linked items (points on ways, addr:street links, relations)
1342 -- Note that addr:street links can only be indexed once the street itself is indexed
1343 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1345 -- Is this node part of a relation?
1346 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1348 -- At the moment we only process one type of relation - associatedStreet
1349 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1350 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1351 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1352 --RAISE WARNING 'node in relation %',relation;
1353 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1354 and rank_search = 26 INTO NEW.parent_place_id;
1360 --RAISE WARNING 'x1';
1361 -- Is this node part of a way?
1362 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1363 --RAISE WARNING '%', way;
1364 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1366 --RAISE WARNING '%', location;
1367 -- Way IS a road then we are on it - that must be our road
1368 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1369 --RAISE WARNING 'node in way that is a street %',location;
1370 NEW.parent_place_id := location.place_id;
1373 -- Is the WAY part of a relation
1374 IF NEW.parent_place_id IS NULL THEN
1375 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1377 -- At the moment we only process one type of relation - associatedStreet
1378 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1379 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1380 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1381 --RAISE WARNING 'node in way that is in a relation %',relation;
1382 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1383 and rank_search = 26 INTO NEW.parent_place_id;
1390 -- If the way contains an explicit name of a street copy it
1391 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1392 --RAISE WARNING 'node in way that has a streetname %',location;
1393 NEW.street := location.street;
1396 -- If this way is a street interpolation line then it is probably as good as we are going to get
1397 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1398 -- Try and find a way that is close roughly parellel to this line
1399 FOR relation IN SELECT place_id FROM placex
1400 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1401 and st_geometrytype(location.geometry) in ('ST_LineString')
1402 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1403 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1404 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1406 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1407 NEW.parent_place_id := relation.place_id;
1416 --RAISE WARNING 'x2';
1418 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1419 -- Is this way part of a relation?
1420 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1422 -- At the moment we only process one type of relation - associatedStreet
1423 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1424 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1425 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1426 --RAISE WARNING 'way that is in a relation %',relation;
1427 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1428 and rank_search = 26 INTO NEW.parent_place_id;
1435 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1437 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1438 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1439 IF address_street_word_id IS NOT NULL THEN
1440 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1441 NEW.parent_place_id := location.place_id;
1446 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1447 -- Still nothing, just use the nearest road
1448 IF NEW.parent_place_id IS NULL THEN
1449 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1450 NEW.parent_place_id := location.place_id;
1455 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1457 -- If we didn't find any road fallback to standard method
1458 IF NEW.parent_place_id IS NOT NULL THEN
1460 -- Add the street to the address as zero distance to force to front of list
1461 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1462 address_havelevel[26] := true;
1464 -- Import address details from parent, reclculating distance in process
1465 -- 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
1466 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1467 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1469 -- Get the details of the parent road
1470 select * from search_name where place_id = NEW.parent_place_id INTO location;
1471 NEW.calculated_country_code := location.country_code;
1473 --RAISE WARNING '%', NEW.name;
1474 -- If there is no name it isn't searchable, don't bother to create a search record
1475 IF NEW.name is NULL THEN
1479 -- Merge address from parent
1480 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1482 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1483 -- Just be happy with inheriting from parent road only
1485 IF NEW.rank_search <= 25 THEN
1486 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1489 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);
1496 -- RAISE WARNING ' INDEXING Started:';
1497 -- RAISE WARNING ' INDEXING: %',NEW;
1499 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1501 -- see if we have any special relation members
1502 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1504 -- RAISE WARNING 'get_osm_rel_members, label';
1505 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1507 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1508 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1510 -- If we don't already have one use this as the centre point of the geometry
1511 IF NEW.centroid IS NULL THEN
1512 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1515 -- merge in the label name, re-init word vector
1516 NEW.name := linkedPlacex.name || NEW.name;
1517 name_vector := make_keywords(NEW.name);
1519 -- merge in extra tags
1520 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1522 -- mark the linked place (excludes from search results)
1523 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1527 IF NEW.centroid IS NULL THEN
1529 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1531 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1532 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1534 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1535 -- But that can be fixed by explicitly setting the label in the data
1536 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1537 AND NEW.rank_search = linkedPlacex.rank_search THEN
1540 -- If we don't already have one use this as the centre point of the geometry
1541 IF NEW.centroid IS NULL THEN
1542 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1545 -- merge in the name, re-init word vector
1546 NEW.name := linkedPlacex.name || NEW.name;
1547 name_vector := make_keywords(NEW.name);
1549 -- merge in extra tags
1550 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1552 -- mark the linked place (excludes from search results)
1553 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1555 -- keep a note of the node id in case we need it for wikipedia in a bit
1556 linked_node_id := linkedPlacex.osm_id;
1563 -- not found one yet? how about doing a name search
1564 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1566 FOR linkedPlacex IN select placex.* from placex WHERE
1567 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1568 AND placex.rank_search = NEW.rank_search
1569 AND placex.place_id != NEW.place_id
1570 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1571 AND st_covers(NEW.geometry, placex.geometry)
1574 -- If we don't already have one use this as the centre point of the geometry
1575 IF NEW.centroid IS NULL THEN
1576 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1579 -- merge in the name, re-init word vector
1580 NEW.name := linkedPlacex.name || NEW.name;
1581 name_vector := make_keywords(NEW.name);
1583 -- merge in extra tags
1584 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1586 -- mark the linked place (excludes from search results)
1587 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1589 -- keep a note of the node id in case we need it for wikipedia in a bit
1590 linked_node_id := linkedPlacex.osm_id;
1594 IF NEW.centroid IS NOT NULL THEN
1595 place_centroid := NEW.centroid;
1598 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1599 IF NEW.importance is null THEN
1600 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1602 -- Still null? how about looking it up by the node id
1603 IF NEW.importance IS NULL THEN
1604 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;
1609 NEW.parent_place_id = 0;
1610 parent_place_id_rank = 0;
1612 -- convert isin to array of tokenids
1613 isin_tokens := '{}'::int[];
1614 IF NEW.isin IS NOT NULL THEN
1615 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1616 IF array_upper(isin, 1) IS NOT NULL THEN
1617 FOR i IN 1..array_upper(isin, 1) LOOP
1618 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1619 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1620 isin_tokens := isin_tokens || address_street_word_id;
1625 IF NEW.postcode IS NOT NULL THEN
1626 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1627 IF array_upper(isin, 1) IS NOT NULL THEN
1628 FOR i IN 1..array_upper(isin, 1) LOOP
1629 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1630 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1631 isin_tokens := isin_tokens || address_street_word_id;
1636 -- RAISE WARNING 'ISIN: %', isin_tokens;
1638 -- Process area matches
1639 location_rank_search := 0;
1640 location_distance := 0;
1641 location_parent := NULL;
1642 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1643 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1645 --RAISE WARNING ' AREA: %',location;
1647 IF location.rank_address != location_rank_search THEN
1648 location_rank_search := location.rank_address;
1649 location_distance := location.distance * 1.5;
1652 IF location.distance < location_distance OR NOT location.isguess THEN
1654 location_isaddress := NOT address_havelevel[location.rank_address];
1655 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1656 location_isaddress := ST_Contains(location_parent,location.centroid);
1659 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1660 -- Add it to the list of search terms
1661 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1662 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1664 IF location_isaddress THEN
1665 address_havelevel[location.rank_address] := true;
1666 IF NOT location.isguess THEN
1667 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1671 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1673 IF location.rank_address > parent_place_id_rank THEN
1674 NEW.parent_place_id = location.place_id;
1675 parent_place_id_rank = location.rank_address;
1682 -- try using the isin value to find parent places
1683 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1684 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1685 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1687 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1689 --RAISE WARNING ' ISIN: %',location;
1691 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1692 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1693 address_havelevel[location.rank_address] := true;
1695 IF location.rank_address > parent_place_id_rank THEN
1696 NEW.parent_place_id = location.place_id;
1697 parent_place_id_rank = location.rank_address;
1705 -- for long ways we should add search terms for the entire length
1706 IF st_length(NEW.geometry) > 0.05 THEN
1708 location_rank_search := 0;
1709 location_distance := 0;
1711 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1713 IF location.rank_address != location_rank_search THEN
1714 location_rank_search := location.rank_address;
1715 location_distance := location.distance * 1.5;
1718 IF location.distance < location_distance THEN
1720 -- Add it to the list of search terms
1721 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1722 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1730 -- if we have a name add this to the name search table
1731 IF NEW.name IS NOT NULL THEN
1733 IF NEW.rank_search <= 25 THEN
1734 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1737 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1738 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1741 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);
1743 -- 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);
1746 -- If we've not managed to pick up a better one - default centroid
1747 IF NEW.centroid IS NULL THEN
1748 NEW.centroid := place_centroid;
1758 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1764 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1766 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1767 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1768 update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1769 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1771 IF OLD.rank_address < 30 THEN
1773 -- mark everything linked to this place for re-indexing
1774 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1775 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1776 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1778 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1779 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1781 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1782 b := deleteRoad(OLD.partition, OLD.place_id);
1784 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1785 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1786 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1790 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1792 IF OLD.rank_address < 26 THEN
1793 b := deleteLocationArea(OLD.partition, OLD.place_id);
1796 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1798 IF OLD.name is not null THEN
1799 b := deleteSearchName(OLD.partition, OLD.place_id);
1802 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1804 DELETE FROM place_addressline where place_id = OLD.place_id;
1806 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1808 -- remove from tables for special search
1809 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1810 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1812 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1815 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1823 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1829 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1831 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1832 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1833 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1838 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;
1846 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1851 existingplacex RECORD;
1852 existinggeometry GEOMETRY;
1853 existingplace_id BIGINT;
1858 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1859 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1861 IF FALSE and NEW.osm_type = 'R' THEN
1862 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;
1863 --DEBUG: RAISE WARNING '%', existingplacex;
1866 -- Just block these - lots and pointless
1867 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1870 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1874 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
1875 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1876 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1877 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1881 -- Patch in additional country names
1882 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1883 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1886 -- Have we already done this place?
1887 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;
1889 -- Get the existing place_id
1890 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;
1892 -- Handle a place changing type by removing the old data
1893 -- My generated 'place' types are causing havok because they overlap with real keys
1894 -- TODO: move them to their own special purpose key/class to avoid collisions
1895 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1896 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');
1899 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1900 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1903 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1904 AND st_area(existing.geometry) > 0.02
1905 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1906 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1908 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1909 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1913 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1914 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1916 -- 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
1917 IF existingplacex.osm_type IS NULL THEN
1919 IF existing.osm_type IS NOT NULL THEN
1920 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1923 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1924 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1925 street, isin, postcode, country_code, extratags, geometry)
1926 values (NEW.osm_type
1941 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
1946 -- Various ways to do the update
1948 -- Debug, what's changed?
1950 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1951 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1953 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1954 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1956 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1957 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1959 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1960 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1962 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1963 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1965 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1966 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1970 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1971 IF existing.geometry::text != NEW.geometry::text
1972 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1973 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1976 -- Get the version of the geometry actually used (in placex table)
1977 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;
1979 -- Performance limit
1980 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1982 -- 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
1983 update placex set indexed_status = 2 where indexed_status = 0 and
1984 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1985 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1986 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1988 update placex set indexed_status = 2 where indexed_status = 0 and
1989 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1990 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1991 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1997 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1998 IF FALSE AND existingplacex.rank_search < 26
1999 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2000 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2001 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2002 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2003 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2004 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2007 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2009 IF st_area(NEW.geometry) < 0.5 THEN
2010 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2011 and placex.place_id = place_addressline.place_id and indexed_status = 0
2012 and (rank_search < 28 or name is not null);
2019 -- Anything else has changed - reindex the lot
2020 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2021 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2022 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2023 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2024 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2025 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2027 -- performance, can't take the load of re-indexing a whole country / huge area
2028 IF st_area(NEW.geometry) < 0.5 THEN
2029 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2030 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2037 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2038 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2039 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2040 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2041 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2042 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2043 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2044 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2045 OR existing.geometry::text != NEW.geometry::text
2050 housenumber = NEW.housenumber,
2051 street = NEW.street,
2053 postcode = NEW.postcode,
2054 country_code = NEW.country_code,
2055 extratags = NEW.extratags,
2056 geometry = NEW.geometry
2057 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2061 housenumber = NEW.housenumber,
2062 street = NEW.street,
2064 postcode = NEW.postcode,
2065 country_code = NEW.country_code,
2066 parent_place_id = null,
2067 extratags = NEW.extratags,
2069 geometry = NEW.geometry
2070 where place_id = existingplacex.place_id;
2074 -- Abort the add (we modified the existing place instead)
2078 $$ LANGUAGE plpgsql;
2080 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2087 IF name is null THEN
2091 search := languagepref;
2093 FOR j IN 1..array_upper(search, 1) LOOP
2094 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2095 return trim(name->search[j]);
2102 LANGUAGE plpgsql IMMUTABLE;
2104 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2107 searchnodes INTEGER[];
2112 searchnodes := '{}';
2113 FOR j IN 1..array_upper(way_ids, 1) LOOP
2115 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2117 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2118 searchnodes := searchnodes || location.nodes;
2123 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2126 LANGUAGE plpgsql IMMUTABLE;
2128 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2139 search := ARRAY['ref'];
2142 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2145 select rank_address,name,distance,length(name::text) as namelength
2146 from place_addressline join placex on (address_place_id = placex.place_id)
2147 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2148 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2150 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2151 FOR j IN 1..array_upper(search, 1) LOOP
2152 FOR k IN 1..array_upper(location.name, 1) LOOP
2153 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
2154 result[(100 - location.rank_address)] := trim(location.name[k].value);
2155 found := location.rank_address;
2162 RETURN array_to_string(result,', ');
2167 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2179 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2180 currresult := trim(get_name_by_language(location.name, languagepref));
2181 IF currresult != prevresult AND currresult IS NOT NULL THEN
2182 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2183 prevresult := currresult;
2187 RETURN array_to_string(result,', ');
2192 DROP TYPE addressline CASCADE;
2193 create type addressline as (
2200 admin_level INTEGER,
2203 rank_address INTEGER,
2207 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2210 for_place_id BIGINT;
2215 countrylocation RECORD;
2216 searchcountrycode varchar(2);
2217 searchhousenumber TEXT;
2218 searchhousename HSTORE;
2219 searchrankaddress INTEGER;
2220 searchpostcode TEXT;
2227 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2228 WHERE place_id = in_place_id
2229 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2231 IF for_place_id IS NULL THEN
2232 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2233 WHERE place_id = in_place_id
2234 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2237 IF for_place_id IS NULL THEN
2238 select parent_place_id, calculated_country_code, housenumber, rank_address, postcode, name, class, type from placex
2239 WHERE place_id = in_place_id and rank_address = 30
2240 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2243 IF for_place_id IS NULL THEN
2244 for_place_id := in_place_id;
2245 select calculated_country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2246 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2249 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2252 hadcountry := false;
2254 select placex.place_id, osm_type, osm_id,
2255 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2256 class, type, admin_level, true as fromarea, true as isaddress,
2257 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2258 0 as distance, calculated_country_code
2260 where place_id = for_place_id
2262 --RAISE WARNING '%',location;
2263 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2264 searchcountrycode := location.calculated_country_code;
2266 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2267 location.isaddress := FALSE;
2269 IF location.rank_address = 4 AND location.isaddress THEN
2272 IF location.rank_address < 4 AND NOT hadcountry THEN
2273 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2274 IF countryname IS NOT NULL THEN
2275 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2276 RETURN NEXT countrylocation;
2279 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2280 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2281 location.distance)::addressline;
2282 RETURN NEXT countrylocation;
2283 found := location.rank_address;
2287 select placex.place_id, osm_type, osm_id,
2288 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2289 class, type, admin_level, fromarea, isaddress,
2290 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,
2291 distance,calculated_country_code
2292 from place_addressline join placex on (address_place_id = placex.place_id)
2293 where place_addressline.place_id = for_place_id
2294 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2295 and address_place_id != for_place_id
2296 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2297 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2299 --RAISE WARNING '%',location;
2300 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2301 searchcountrycode := location.calculated_country_code;
2303 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2304 location.isaddress := FALSE;
2306 IF location.rank_address = 4 AND location.isaddress THEN
2309 IF location.rank_address < 4 AND NOT hadcountry THEN
2310 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2311 IF countryname IS NOT NULL THEN
2312 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2313 RETURN NEXT countrylocation;
2316 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2317 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2318 location.distance)::addressline;
2319 RETURN NEXT countrylocation;
2320 found := location.rank_address;
2324 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2325 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2326 IF countryname IS NOT NULL THEN
2327 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2328 RETURN NEXT location;
2332 IF searchcountrycode IS NOT NULL THEN
2333 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2334 RETURN NEXT location;
2337 IF searchhousename IS NOT NULL THEN
2338 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2339 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2340 RETURN NEXT location;
2343 IF searchhousenumber IS NOT NULL THEN
2344 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2345 RETURN NEXT location;
2348 IF searchpostcode IS NOT NULL THEN
2349 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2350 RETURN NEXT location;
2358 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2361 result place_boundingbox;
2362 numfeatures integer;
2364 select * from place_boundingbox into result where place_id = search_place_id;
2365 IF result.place_id IS NULL THEN
2366 -- remove isaddress = true because if there is a matching polygon it always wins
2367 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2368 insert into place_boundingbox select place_id,
2369 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2370 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2371 numfeatures, ST_Area(geometry),
2372 geometry as area from location_area where place_id = search_place_id;
2373 select * from place_boundingbox into result where place_id = search_place_id;
2375 IF result.place_id IS NULL THEN
2377 insert into place_boundingbox select address_place_id,
2378 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2379 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2380 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2381 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2382 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)
2383 where address_place_id = search_place_id
2384 -- and (isaddress = true OR place_id = search_place_id)
2385 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2386 group by address_place_id limit 1;
2387 select * from place_boundingbox into result where place_id = search_place_id;
2394 -- don't do the operation if it would be slow
2395 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2398 result place_boundingbox;
2399 numfeatures integer;
2402 select * from place_boundingbox into result where place_id = search_place_id;
2403 IF result IS NULL AND rank > 14 THEN
2404 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2405 insert into place_boundingbox select place_id,
2406 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2407 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2408 numfeatures, ST_Area(geometry),
2409 geometry as area from location_area where place_id = search_place_id;
2410 select * from place_boundingbox into result where place_id = search_place_id;
2412 IF result IS NULL THEN
2413 select rank_search from placex where place_id = search_place_id into rank;
2416 insert into place_boundingbox select address_place_id,
2417 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2418 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2419 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2420 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2421 from place_addressline join placex using (place_id)
2422 where address_place_id = search_place_id
2423 and (isaddress = true OR place_id = search_place_id)
2424 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2425 group by address_place_id limit 1;
2426 select * from place_boundingbox into result where place_id = search_place_id;
2434 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2437 result place_boundingbox;
2438 numfeatures integer;
2442 housenumber = place.housenumber,
2443 street = place.street,
2445 postcode = place.postcode,
2446 country_code = place.country_code,
2447 parent_place_id = null
2449 where placex.place_id = search_place_id
2450 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2451 and place.class = placex.class and place.type = placex.type;
2452 update placex set indexed_status = 2 where place_id = search_place_id;
2453 update placex set indexed_status = 0 where place_id = search_place_id;
2459 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2465 ELSEIF rank < 4 THEN
2467 ELSEIF rank < 8 THEN
2469 ELSEIF rank < 12 THEN
2471 ELSEIF rank < 16 THEN
2473 ELSEIF rank = 16 THEN
2475 ELSEIF rank = 17 THEN
2476 RETURN 'Town / Island';
2477 ELSEIF rank = 18 THEN
2478 RETURN 'Village / Hamlet';
2479 ELSEIF rank = 20 THEN
2481 ELSEIF rank = 21 THEN
2482 RETURN 'Postcode Area';
2483 ELSEIF rank = 22 THEN
2484 RETURN 'Croft / Farm / Locality / Islet';
2485 ELSEIF rank = 23 THEN
2486 RETURN 'Postcode Area';
2487 ELSEIF rank = 25 THEN
2488 RETURN 'Postcode Point';
2489 ELSEIF rank = 26 THEN
2490 RETURN 'Street / Major Landmark';
2491 ELSEIF rank = 27 THEN
2492 RETURN 'Minory Street / Path';
2493 ELSEIF rank = 28 THEN
2494 RETURN 'House / Building';
2496 RETURN 'Other: '||rank;
2503 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2509 ELSEIF rank < 2 THEN
2511 ELSEIF rank < 4 THEN
2513 ELSEIF rank = 5 THEN
2515 ELSEIF rank < 8 THEN
2517 ELSEIF rank < 12 THEN
2519 ELSEIF rank < 16 THEN
2521 ELSEIF rank = 16 THEN
2523 ELSEIF rank = 17 THEN
2524 RETURN 'Town / Village / Hamlet';
2525 ELSEIF rank = 20 THEN
2527 ELSEIF rank = 21 THEN
2528 RETURN 'Postcode Area';
2529 ELSEIF rank = 22 THEN
2530 RETURN 'Croft / Farm / Locality / Islet';
2531 ELSEIF rank = 23 THEN
2532 RETURN 'Postcode Area';
2533 ELSEIF rank = 25 THEN
2534 RETURN 'Postcode Point';
2535 ELSEIF rank = 26 THEN
2536 RETURN 'Street / Major Landmark';
2537 ELSEIF rank = 27 THEN
2538 RETURN 'Minory Street / Path';
2539 ELSEIF rank = 28 THEN
2540 RETURN 'House / Building';
2542 RETURN 'Other: '||rank;
2549 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2556 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2557 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2564 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2572 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2574 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2575 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2577 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2585 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2586 in_endnumber INTEGER, interpolationtype TEXT,
2587 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2591 startnumber INTEGER;
2596 numberrange INTEGER;
2597 rangestartnumber INTEGER;
2598 place_centroid GEOMETRY;
2599 out_partition INTEGER;
2600 out_parent_place_id BIGINT;
2602 address_street_word_id INTEGER;
2606 IF in_endnumber > in_startnumber THEN
2607 startnumber = in_startnumber;
2608 endnumber = in_endnumber;
2610 startnumber = in_endnumber;
2611 endnumber = in_startnumber;
2614 numberrange := endnumber - startnumber;
2615 rangestartnumber := startnumber;
2617 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2618 startnumber := startnumber + 1;
2621 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2623 ELSE -- everything else assumed to be 'all'
2628 -- Filter out really broken tiger data
2629 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2630 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2631 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2632 ST_length(linegeo)/(numberrange::float/stepsize::float);
2636 place_centroid := ST_Centroid(linegeo);
2637 out_partition := get_partition(place_centroid, 'us');
2638 out_parent_place_id := null;
2640 address_street_word_id := get_name_id(make_standard_name(in_street));
2641 IF address_street_word_id IS NOT NULL THEN
2642 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2643 out_parent_place_id := location.place_id;
2647 IF out_parent_place_id IS NULL THEN
2648 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP
2649 out_parent_place_id := location.place_id;
2653 IF out_parent_place_id IS NULL THEN
2654 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2655 out_parent_place_id := location.place_id;
2660 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2661 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2662 values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode,
2663 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2664 newpoints := newpoints + 1;
2672 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2673 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2678 place_centroid GEOMETRY;
2679 out_partition INTEGER;
2680 out_parent_place_id BIGINT;
2682 address_street_word_id INTEGER;
2687 place_centroid := ST_Centroid(pointgeo);
2688 out_partition := get_partition(place_centroid, in_countrycode);
2689 out_parent_place_id := null;
2691 address_street_word_id := get_name_id(make_standard_name(in_street));
2692 IF address_street_word_id IS NOT NULL THEN
2693 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2694 out_parent_place_id := location.place_id;
2698 IF out_parent_place_id IS NULL THEN
2699 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2700 out_parent_place_id := location.place_id;
2704 out_postcode := in_postcode;
2705 IF out_postcode IS NULL THEN
2706 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2708 IF out_postcode IS NULL THEN
2709 out_postcode := getNearestPostcode(out_partition, place_centroid);
2713 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2714 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2715 newpoints := newpoints + 1;
2722 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2729 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2730 IF members[i+1] = member THEN
2731 result := result || members[i];
2740 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2746 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2747 IF members[i+1] = ANY(memberLabels) THEN
2748 RETURN NEXT members[i];
2757 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2758 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2760 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2761 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
2762 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2763 ), '') AS bytea), 'UTF8');
2765 LANGUAGE SQL IMMUTABLE STRICT;
2767 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2771 RETURN decode_url_part(p);
2773 WHEN others THEN return null;
2776 LANGUAGE plpgsql IMMUTABLE;
2778 DROP TYPE wikipedia_article_match CASCADE;
2779 create type wikipedia_article_match as (
2785 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2791 wiki_article_title TEXT;
2792 wiki_article_language TEXT;
2793 result wikipedia_article_match;
2795 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'];
2797 WHILE langs[i] IS NOT NULL LOOP
2798 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2799 IF wiki_article is not null THEN
2800 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2801 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2802 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2803 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2804 wiki_article := replace(wiki_article,' ','_');
2805 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2806 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2807 wiki_article_title := trim(wiki_article);
2808 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;
2810 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2813 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2814 from wikipedia_article
2815 where language = wiki_article_language and
2816 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2818 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2819 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2820 where wikipedia_redirect.language = wiki_article_language and
2821 (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'\\',''))
2822 order by importance desc limit 1 INTO result;
2824 IF result.language is not null THEN
2835 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2836 RETURNS SETOF GEOMETRY
2850 remainingdepth INTEGER;
2855 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2857 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2858 RETURN NEXT geometry;
2862 remainingdepth := maxdepth - 1;
2863 area := ST_AREA(geometry);
2864 IF remainingdepth < 1 OR area < maxarea THEN
2865 RETURN NEXT geometry;
2869 xmin := st_xmin(geometry);
2870 xmax := st_xmax(geometry);
2871 ymin := st_ymin(geometry);
2872 ymax := st_ymax(geometry);
2873 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2875 -- if the geometry completely covers the box don't bother to slice any more
2876 IF ST_AREA(secbox) = area THEN
2877 RETURN NEXT geometry;
2881 xmid := (xmin+xmax)/2;
2882 ymid := (ymin+ymax)/2;
2885 FOR seg IN 1..4 LOOP
2888 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2891 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2894 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2897 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2900 IF st_intersects(geometry, secbox) THEN
2901 secgeo := st_intersection(geometry, secbox);
2902 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2903 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2904 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2906 RETURN NEXT geo.geom;
2918 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2919 RETURNS SETOF GEOMETRY
2924 -- 10000000000 is ~~ 1x1 degree
2925 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2926 RETURN NEXT geo.geom;