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;
773 select * from placex where place_id = search_place_id INTO nextnode;
776 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
778 IF havefirstpoint THEN
780 -- add point to the line string
781 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
782 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
784 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
786 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
788 IF startnumber != endnumber THEN
790 linestr := linestr || ')';
791 --RAISE WARNING 'linestr %',linestr;
792 linegeo := ST_GeomFromText(linestr,4326);
793 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
794 IF (startnumber > endnumber) THEN
795 housenum := endnumber;
796 endnumber := startnumber;
797 startnumber := housenum;
798 linegeo := ST_Reverse(linegeo);
800 orginalstartnumber := startnumber;
801 originalnumberrange := endnumber - startnumber;
803 -- Too much broken data worldwide for this test to be worth using
804 -- IF originalnumberrange > 500 THEN
805 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
808 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
809 startnumber := startnumber + 1;
812 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
813 startnumber := startnumber + 2;
815 ELSE -- everything else assumed to be 'all'
816 startnumber := startnumber + 1;
820 endnumber := endnumber - 1;
821 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
822 FOR housenum IN startnumber..endnumber BY stepsize LOOP
823 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
824 -- ideally postcodes should move up to the way
825 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
826 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
827 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
828 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));
829 newpoints := newpoints + 1;
830 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
833 havefirstpoint := false;
837 IF NOT havefirstpoint THEN
838 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
839 IF startnumber IS NOT NULL AND startnumber > 0 THEN
840 havefirstpoint := true;
841 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
842 prevnode := nextnode;
844 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
850 --RAISE WARNING 'interpolation points % ',newpoints;
857 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
863 country_code VARCHAR(2);
864 default_language VARCHAR(10);
868 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
871 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
872 -- RAISE WARNING 'bad highway %',NEW.osm_id;
875 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
876 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
880 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
881 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
882 RAISE WARNING 'invalid geometry %',NEW.osm_id;
886 IF NEW.osm_type = 'R' THEN
887 -- invalid multipolygons can crash postgis, don't even bother to try!
890 NEW.geometry := ST_buffer(NEW.geometry,0);
891 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
892 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
897 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
899 NEW.place_id := nextval('seq_place');
900 NEW.indexed_status := 1; --STATUS_NEW
902 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
904 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
905 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
907 -- copy 'name' to or from the default language (if there is a default language)
908 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
909 default_language := get_country_language_code(NEW.calculated_country_code);
910 IF default_language IS NOT NULL THEN
911 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
912 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
913 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
914 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
919 IF NEW.admin_level > 15 THEN
920 NEW.admin_level := 15;
923 IF NEW.housenumber IS NOT NULL THEN
924 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
927 IF NEW.osm_type = 'X' THEN
928 -- E'X'ternal records should already be in the right format so do nothing
930 NEW.rank_search := 30;
931 NEW.rank_address := NEW.rank_search;
933 -- By doing in postgres we have the country available to us - currently only used for postcode
934 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
936 IF NEW.postcode IS NULL THEN
937 -- most likely just a part of a multipolygon postcode boundary, throw it away
941 NEW.name := 'ref'=>NEW.postcode;
943 IF NEW.calculated_country_code = 'gb' THEN
945 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
946 NEW.rank_search := 25;
947 NEW.rank_address := 5;
948 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
949 NEW.rank_search := 23;
950 NEW.rank_address := 5;
951 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
952 NEW.rank_search := 21;
953 NEW.rank_address := 5;
956 ELSEIF NEW.calculated_country_code = 'de' THEN
958 IF NEW.postcode ~ '^([0-9]{5})$' THEN
959 NEW.rank_search := 21;
960 NEW.rank_address := 11;
964 -- Guess at the postcode format and coverage (!)
965 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
966 NEW.rank_search := 21;
967 NEW.rank_address := 11;
969 -- Does it look splitable into and area and local code?
970 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
972 IF postcode IS NOT NULL THEN
973 NEW.rank_search := 25;
974 NEW.rank_address := 11;
975 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
976 NEW.rank_search := 21;
977 NEW.rank_address := 11;
982 ELSEIF NEW.class = 'place' THEN
983 IF NEW.type in ('continent') THEN
984 NEW.rank_search := 2;
985 NEW.rank_address := NEW.rank_search;
986 NEW.calculated_country_code := NULL;
987 ELSEIF NEW.type in ('sea') THEN
988 NEW.rank_search := 2;
989 NEW.rank_address := 0;
990 NEW.calculated_country_code := NULL;
991 ELSEIF NEW.type in ('country') THEN
992 NEW.rank_search := 4;
993 NEW.rank_address := NEW.rank_search;
994 ELSEIF NEW.type in ('state') THEN
995 NEW.rank_search := 8;
996 NEW.rank_address := NEW.rank_search;
997 ELSEIF NEW.type in ('region') THEN
998 NEW.rank_search := 18; -- dropped from previous value of 10
999 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1000 ELSEIF NEW.type in ('county') THEN
1001 NEW.rank_search := 12;
1002 NEW.rank_address := NEW.rank_search;
1003 ELSEIF NEW.type in ('city') THEN
1004 NEW.rank_search := 16;
1005 NEW.rank_address := NEW.rank_search;
1006 ELSEIF NEW.type in ('island') THEN
1007 NEW.rank_search := 17;
1008 NEW.rank_address := 0;
1009 ELSEIF NEW.type in ('town') THEN
1010 NEW.rank_search := 18;
1011 NEW.rank_address := 16;
1012 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1013 NEW.rank_search := 19;
1014 NEW.rank_address := 16;
1015 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1016 NEW.rank_search := 18;
1017 NEW.rank_address := 17;
1018 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1019 NEW.rank_search := 17;
1020 NEW.rank_address := 18;
1021 ELSEIF NEW.type in ('moor') THEN
1022 NEW.rank_search := 17;
1023 NEW.rank_address := 0;
1024 ELSEIF NEW.type in ('national_park') THEN
1025 NEW.rank_search := 18;
1026 NEW.rank_address := 18;
1027 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1028 NEW.rank_search := 20;
1029 NEW.rank_address := NEW.rank_search;
1030 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1031 NEW.rank_search := 20;
1032 NEW.rank_address := 0;
1033 -- Irish townlands, tagged as place=locality and locality=townland
1034 IF (NEW.extratags -> 'locality') = 'townland' THEN
1035 NEW.rank_address := 20;
1037 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1038 NEW.rank_search := 22;
1039 NEW.rank_address := 22;
1040 ELSEIF NEW.type in ('airport','street') THEN
1041 NEW.rank_search := 26;
1042 NEW.rank_address := NEW.rank_search;
1043 ELSEIF NEW.type in ('house','building') THEN
1044 NEW.rank_search := 30;
1045 NEW.rank_address := NEW.rank_search;
1046 ELSEIF NEW.type in ('houses') THEN
1047 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1048 -- insert new point into place for each derived building
1049 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1050 NEW.rank_search := 28;
1051 NEW.rank_address := 0;
1054 ELSEIF NEW.class = 'boundary' THEN
1055 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1056 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1059 NEW.rank_search := NEW.admin_level * 2;
1060 NEW.rank_address := NEW.rank_search;
1061 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1062 NEW.rank_search := 22;
1063 NEW.rank_address := NEW.rank_search;
1064 -- any feature more than 5 square miles is probably worth indexing
1065 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1066 NEW.rank_search := 22;
1067 NEW.rank_address := NEW.rank_search;
1068 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1069 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1070 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1072 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1074 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1076 ELSEIF NEW.class = 'waterway' THEN
1077 NEW.rank_address := 17;
1078 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
1079 NEW.rank_search := 27;
1080 NEW.rank_address := NEW.rank_search;
1081 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1082 NEW.rank_search := 26;
1083 NEW.rank_address := NEW.rank_search;
1084 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1085 NEW.rank_search := 4;
1086 NEW.rank_address := NEW.rank_search;
1087 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1089 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1090 NEW.rank_search := 18;
1091 NEW.rank_address := 0;
1096 IF NEW.rank_search > 30 THEN
1097 NEW.rank_search := 30;
1100 IF NEW.rank_address > 30 THEN
1101 NEW.rank_address := 30;
1104 IF (NEW.extratags -> 'capital') = 'yes' THEN
1105 NEW.rank_search := NEW.rank_search - 1;
1108 -- a country code make no sense below rank 4 (country)
1109 IF NEW.rank_address < 4 THEN
1110 NEW.calculated_country_code := NULL;
1113 -- Block import below rank 22
1114 -- IF NEW.rank_search > 22 THEN
1118 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1120 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1122 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1123 -- Performance: We just can't handle re-indexing for country level changes
1124 IF st_area(NEW.geometry) < 1 THEN
1125 -- mark items within the geometry for re-indexing
1126 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1128 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1129 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1130 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);
1131 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1132 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);
1135 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1137 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1138 IF NEW.type='postcode' THEN
1140 ELSEIF NEW.rank_search < 16 THEN
1142 ELSEIF NEW.rank_search < 18 THEN
1144 ELSEIF NEW.rank_search < 20 THEN
1146 ELSEIF NEW.rank_search = 21 THEN
1148 ELSEIF NEW.rank_search < 24 THEN
1150 ELSEIF NEW.rank_search < 26 THEN
1151 diameter := 0.002; -- 100 to 200 meters
1152 ELSEIF NEW.rank_search < 28 THEN
1153 diameter := 0.001; -- 50 to 100 meters
1155 IF diameter > 0 THEN
1156 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1157 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);
1162 -- add to tables for special search
1163 -- Note: won't work on initial import because the classtype tables
1164 -- do not yet exist. It won't hurt either.
1165 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1166 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1168 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1169 USING NEW.place_id, ST_Centroid(NEW.geometry);
1173 -- IF NEW.rank_search < 26 THEN
1174 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1183 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1188 place_centroid GEOMETRY;
1190 search_maxdistance FLOAT[];
1191 search_mindistance FLOAT[];
1192 address_havelevel BOOLEAN[];
1193 -- search_scores wordscore[];
1194 -- search_scores_pos INTEGER;
1201 relation_members TEXT[];
1203 linkedplacex RECORD;
1204 search_diameter FLOAT;
1205 search_prevdiameter FLOAT;
1206 search_maxrank INTEGER;
1207 address_maxrank INTEGER;
1208 address_street_word_id INTEGER;
1209 parent_place_id_rank BIGINT;
1214 location_rank_search INTEGER;
1215 location_distance FLOAT;
1219 default_language TEXT;
1220 name_vector INTEGER[];
1221 nameaddress_vector INTEGER[];
1223 linked_node_id BIGINT;
1228 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1232 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1234 --RAISE WARNING '%',NEW.place_id;
1235 --RAISE WARNING '%', NEW;
1237 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1238 -- Silently do nothing
1243 IF OLD.indexed_status = 100 THEN
1244 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1245 delete from placex where place_id = OLD.place_id;
1249 IF OLD.indexed_status != 0 THEN
1250 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1252 NEW.indexed_date = now();
1254 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1255 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1259 IF OLD.indexed_status > 0 THEN
1260 result := deleteSearchName(NEW.partition, NEW.place_id);
1261 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1262 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1263 result := deleteRoad(NEW.partition, NEW.place_id);
1264 result := deleteLocationArea(NEW.partition, NEW.place_id);
1265 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1268 -- Speed up searches - just use the centroid of the feature
1269 -- cheaper but less acurate
1270 place_centroid := ST_PointOnSurface(NEW.geometry);
1271 NEW.centroid := null;
1273 -- reclaculate country and partition
1274 IF NEW.rank_search >= 4 THEN
1275 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1276 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1278 NEW.calculated_country_code := NULL;
1280 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1281 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1283 -- Adding ourselves to the list simplifies address calculations later
1284 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1286 -- What level are we searching from
1287 search_maxrank := NEW.rank_search;
1289 -- Thought this wasn't needed but when we add new languages to the country_name table
1290 -- we need to update the existing names
1291 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1292 default_language := get_country_language_code(NEW.calculated_country_code);
1293 IF default_language IS NOT NULL THEN
1294 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1295 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1296 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1297 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1302 -- Initialise the name vector using our name
1303 name_vector := make_keywords(NEW.name);
1304 nameaddress_vector := '{}'::int[];
1306 -- some tag combinations add a special id for search
1307 tagpairid := get_tagpair(NEW.class,NEW.type);
1308 IF tagpairid IS NOT NULL THEN
1309 name_vector := name_vector + tagpairid;
1313 address_havelevel[i] := false;
1316 NEW.importance := null;
1317 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1318 IF NEW.importance IS NULL THEN
1319 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;
1322 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1324 -- For low level elements we inherit from our parent road
1325 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1327 --RAISE WARNING 'finding street for %', NEW;
1329 NEW.parent_place_id := null;
1331 -- to do that we have to find our parent road
1332 -- Copy data from linked items (points on ways, addr:street links, relations)
1333 -- Note that addr:street links can only be indexed once the street itself is indexed
1334 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1336 -- Is this node part of a relation?
1337 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1339 -- At the moment we only process one type of relation - associatedStreet
1340 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1341 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1342 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1343 --RAISE WARNING 'node in relation %',relation;
1344 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1345 and rank_search = 26 INTO NEW.parent_place_id;
1351 --RAISE WARNING 'x1';
1352 -- Is this node part of a way?
1353 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1354 --RAISE WARNING '%', way;
1355 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1357 --RAISE WARNING '%', location;
1358 -- Way IS a road then we are on it - that must be our road
1359 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1360 --RAISE WARNING 'node in way that is a street %',location;
1361 NEW.parent_place_id := location.place_id;
1364 -- Is the WAY part of a relation
1365 IF NEW.parent_place_id IS NULL THEN
1366 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1368 -- At the moment we only process one type of relation - associatedStreet
1369 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1370 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1371 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1372 --RAISE WARNING 'node in way that is in a relation %',relation;
1373 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1374 and rank_search = 26 INTO NEW.parent_place_id;
1381 -- If the way contains an explicit name of a street copy it
1382 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1383 --RAISE WARNING 'node in way that has a streetname %',location;
1384 NEW.street := location.street;
1387 -- If this way is a street interpolation line then it is probably as good as we are going to get
1388 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1389 -- Try and find a way that is close roughly parellel to this line
1390 FOR relation IN SELECT place_id FROM placex
1391 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1392 and st_geometrytype(location.geometry) in ('ST_LineString')
1393 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1394 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1395 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1397 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1398 NEW.parent_place_id := relation.place_id;
1407 --RAISE WARNING 'x2';
1409 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1410 -- Is this way part of a relation?
1411 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1413 -- At the moment we only process one type of relation - associatedStreet
1414 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1415 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1416 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1417 --RAISE WARNING 'way that is in a relation %',relation;
1418 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1419 and rank_search = 26 INTO NEW.parent_place_id;
1426 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1428 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1429 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1430 IF address_street_word_id IS NOT NULL THEN
1431 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1432 NEW.parent_place_id := location.place_id;
1437 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1438 -- Still nothing, just use the nearest road
1439 IF NEW.parent_place_id IS NULL THEN
1440 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1441 NEW.parent_place_id := location.place_id;
1446 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1448 -- If we didn't find any road fallback to standard method
1449 IF NEW.parent_place_id IS NOT NULL THEN
1451 -- Add the street to the address as zero distance to force to front of list
1452 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1453 address_havelevel[26] := true;
1455 -- Import address details from parent, reclculating distance in process
1456 -- 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
1457 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1458 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1460 -- Get the details of the parent road
1461 select * from search_name where place_id = NEW.parent_place_id INTO location;
1462 NEW.calculated_country_code := location.country_code;
1464 --RAISE WARNING '%', NEW.name;
1465 -- If there is no name it isn't searchable, don't bother to create a search record
1466 IF NEW.name is NULL THEN
1470 -- Merge address from parent
1471 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1473 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1474 -- Just be happy with inheriting from parent road only
1476 IF NEW.rank_search <= 25 THEN
1477 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1480 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);
1487 -- RAISE WARNING ' INDEXING Started:';
1488 -- RAISE WARNING ' INDEXING: %',NEW;
1490 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1492 -- see if we have any special relation members
1493 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1495 -- RAISE WARNING 'get_osm_rel_members, label';
1496 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1498 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1499 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1501 -- If we don't already have one use this as the centre point of the geometry
1502 IF NEW.centroid IS NULL THEN
1503 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1506 -- merge in the label name, re-init word vector
1507 NEW.name := linkedPlacex.name || NEW.name;
1508 name_vector := make_keywords(NEW.name);
1510 -- merge in extra tags
1511 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1513 -- mark the linked place (excludes from search results)
1514 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1518 IF NEW.centroid IS NULL THEN
1520 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1522 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1523 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1525 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1526 -- But that can be fixed by explicitly setting the label in the data
1527 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1528 AND NEW.rank_search = linkedPlacex.rank_search THEN
1531 -- If we don't already have one use this as the centre point of the geometry
1532 IF NEW.centroid IS NULL THEN
1533 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1536 -- merge in the name, re-init word vector
1537 NEW.name := linkedPlacex.name || NEW.name;
1538 name_vector := make_keywords(NEW.name);
1540 -- merge in extra tags
1541 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1543 -- mark the linked place (excludes from search results)
1544 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1546 -- keep a note of the node id in case we need it for wikipedia in a bit
1547 linked_node_id := linkedPlacex.osm_id;
1554 -- not found one yet? how about doing a name search
1555 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1557 FOR linkedPlacex IN select placex.* from placex WHERE
1558 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1559 AND placex.rank_search = NEW.rank_search
1560 AND placex.place_id != NEW.place_id
1561 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1562 AND st_covers(NEW.geometry, placex.geometry)
1565 -- If we don't already have one use this as the centre point of the geometry
1566 IF NEW.centroid IS NULL THEN
1567 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1570 -- merge in the name, re-init word vector
1571 NEW.name := linkedPlacex.name || NEW.name;
1572 name_vector := make_keywords(NEW.name);
1574 -- merge in extra tags
1575 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1577 -- mark the linked place (excludes from search results)
1578 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1580 -- keep a note of the node id in case we need it for wikipedia in a bit
1581 linked_node_id := linkedPlacex.osm_id;
1585 IF NEW.centroid IS NOT NULL THEN
1586 place_centroid := NEW.centroid;
1589 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1590 IF NEW.importance is null THEN
1591 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1593 -- Still null? how about looking it up by the node id
1594 IF NEW.importance IS NULL THEN
1595 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;
1600 NEW.parent_place_id = 0;
1601 parent_place_id_rank = 0;
1603 -- convert isin to array of tokenids
1604 isin_tokens := '{}'::int[];
1605 IF NEW.isin IS NOT NULL THEN
1606 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1607 IF array_upper(isin, 1) IS NOT NULL THEN
1608 FOR i IN 1..array_upper(isin, 1) LOOP
1609 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1610 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1611 isin_tokens := isin_tokens || address_street_word_id;
1616 IF NEW.postcode IS NOT NULL THEN
1617 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1618 IF array_upper(isin, 1) IS NOT NULL THEN
1619 FOR i IN 1..array_upper(isin, 1) LOOP
1620 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1621 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1622 isin_tokens := isin_tokens || address_street_word_id;
1627 -- RAISE WARNING 'ISIN: %', isin_tokens;
1629 -- Process area matches
1630 location_rank_search := 100;
1631 location_distance := 0;
1632 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1633 FOR location IN SELECT distinct * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1635 --RAISE WARNING ' AREA: %',location;
1637 IF location.rank_search < location_rank_search THEN
1638 location_rank_search := location.rank_search;
1639 location_distance := location.distance * 1.5;
1642 IF location.distance < location_distance OR NOT location.isguess THEN
1644 -- Add it to the list of search terms
1645 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1646 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1647 address_havelevel[location.rank_address] := true;
1649 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1651 IF location.rank_address > parent_place_id_rank THEN
1652 NEW.parent_place_id = location.place_id;
1653 parent_place_id_rank = location.rank_address;
1660 -- try using the isin value to find parent places
1661 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1662 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1663 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1665 FOR location IN SELECT distinct * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1667 --RAISE WARNING ' ISIN: %',location;
1669 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1670 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1671 address_havelevel[location.rank_address] := true;
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;
1683 -- for long ways we should add search terms for the entire length
1684 IF st_length(NEW.geometry) > 0.05 THEN
1686 location_rank_search := 100;
1687 location_distance := 0;
1689 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1691 IF location.rank_search < location_rank_search THEN
1692 location_rank_search := location.rank_search;
1693 location_distance := location.distance * 1.5;
1696 IF location.distance < location_distance THEN
1698 -- Add it to the list of search terms
1699 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1700 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1708 -- if we have a name add this to the name search table
1709 IF NEW.name IS NOT NULL THEN
1711 IF NEW.rank_search <= 25 THEN
1712 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1715 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1716 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1719 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);
1721 -- 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);
1724 -- If we've not managed to pick up a better one - default centroid
1725 IF NEW.centroid IS NULL THEN
1726 NEW.centroid := place_centroid;
1736 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1742 RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1744 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1745 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1746 update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1747 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1749 IF OLD.rank_address < 30 THEN
1751 -- mark everything linked to this place for re-indexing
1752 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1753 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1754 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1756 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1757 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1759 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1760 b := deleteRoad(OLD.partition, OLD.place_id);
1762 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1763 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1764 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1768 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1770 IF OLD.rank_address < 26 THEN
1771 b := deleteLocationArea(OLD.partition, OLD.place_id);
1774 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1776 IF OLD.name is not null THEN
1777 b := deleteSearchName(OLD.partition, OLD.place_id);
1780 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1782 DELETE FROM place_addressline where place_id = OLD.place_id;
1784 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1786 -- remove from tables for special search
1787 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1788 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1790 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1793 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1801 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1807 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1809 -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through
1810 IF st_area(OLD.geometry) > 2 THEN
1811 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1816 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;
1824 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1829 existingplacex RECORD;
1830 existinggeometry GEOMETRY;
1831 existingplace_id BIGINT;
1836 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1837 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1839 IF FALSE and NEW.osm_type = 'R' THEN
1840 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;
1841 --DEBUG: RAISE WARNING '%', existingplacex;
1844 -- Just block these - lots and pointless
1845 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1848 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1852 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
1853 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1854 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1855 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1859 -- Patch in additional country names
1860 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1861 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1864 -- Have we already done this place?
1865 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;
1867 -- Get the existing place_id
1868 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;
1870 -- Handle a place changing type by removing the old data
1871 -- My generated 'place' types are causing havok because they overlap with real keys
1872 -- TODO: move them to their own special purpose key/class to avoid collisions
1873 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1874 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');
1877 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1878 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1881 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1882 AND st_area(existing.geometry) > 0.02
1883 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1884 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1886 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1887 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1891 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1892 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1894 -- 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
1895 IF existingplacex.osm_type IS NULL THEN
1897 IF existing.osm_type IS NOT NULL THEN
1898 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1901 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1902 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1903 street, isin, postcode, country_code, extratags, geometry)
1904 values (NEW.osm_type
1919 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
1924 -- Various ways to do the update
1926 -- Debug, what's changed?
1928 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1929 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1931 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1932 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1934 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1935 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1937 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1938 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1940 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1941 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1943 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1944 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1948 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1949 IF existing.geometry::text != NEW.geometry::text
1950 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1951 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1954 -- Get the version of the geometry actually used (in placex table)
1955 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;
1957 -- Performance limit
1958 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1960 -- 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
1961 update placex set indexed_status = 2 where indexed_status = 0 and
1962 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1963 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1964 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1966 update placex set indexed_status = 2 where indexed_status = 0 and
1967 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1968 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1969 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1975 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1976 IF FALSE AND existingplacex.rank_search < 26
1977 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1978 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1979 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1980 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1981 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1982 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1985 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1987 IF st_area(NEW.geometry) < 0.5 THEN
1988 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1989 and placex.place_id = place_addressline.place_id and indexed_status = 0
1990 and (rank_search < 28 or name is not null);
1997 -- Anything else has changed - reindex the lot
1998 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1999 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2000 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2001 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2002 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2003 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2005 -- performance, can't take the load of re-indexing a whole country / huge area
2006 IF st_area(NEW.geometry) < 0.5 THEN
2007 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2008 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2015 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2016 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2017 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2018 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2019 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2020 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2021 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2022 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2023 OR existing.geometry::text != NEW.geometry::text
2028 housenumber = NEW.housenumber,
2029 street = NEW.street,
2031 postcode = NEW.postcode,
2032 country_code = NEW.country_code,
2033 extratags = NEW.extratags,
2034 geometry = NEW.geometry
2035 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2039 housenumber = NEW.housenumber,
2040 street = NEW.street,
2042 postcode = NEW.postcode,
2043 country_code = NEW.country_code,
2044 parent_place_id = null,
2045 extratags = NEW.extratags,
2047 geometry = NEW.geometry
2048 where place_id = existingplacex.place_id;
2052 -- Abort the add (we modified the existing place instead)
2056 $$ LANGUAGE plpgsql;
2058 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2065 IF name is null THEN
2069 search := languagepref;
2071 FOR j IN 1..array_upper(search, 1) LOOP
2072 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2073 return trim(name->search[j]);
2080 LANGUAGE plpgsql IMMUTABLE;
2082 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2085 searchnodes INTEGER[];
2090 searchnodes := '{}';
2091 FOR j IN 1..array_upper(way_ids, 1) LOOP
2093 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2095 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2096 searchnodes := searchnodes || location.nodes;
2101 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2104 LANGUAGE plpgsql IMMUTABLE;
2106 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2117 search := ARRAY['ref'];
2120 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2123 select rank_address,name,distance,length(name::text) as namelength
2124 from place_addressline join placex on (address_place_id = placex.place_id)
2125 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2126 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2128 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2129 FOR j IN 1..array_upper(search, 1) LOOP
2130 FOR k IN 1..array_upper(location.name, 1) LOOP
2131 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
2132 result[(100 - location.rank_address)] := trim(location.name[k].value);
2133 found := location.rank_address;
2140 RETURN array_to_string(result,', ');
2145 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2157 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2158 currresult := trim(get_name_by_language(location.name, languagepref));
2159 IF currresult != prevresult AND currresult IS NOT NULL THEN
2160 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2161 prevresult := currresult;
2165 RETURN array_to_string(result,', ');
2170 DROP TYPE addressline CASCADE;
2171 create type addressline as (
2178 admin_level INTEGER,
2181 rank_address INTEGER,
2185 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2188 for_place_id BIGINT;
2193 countrylocation RECORD;
2194 searchcountrycode varchar(2);
2195 searchhousenumber TEXT;
2196 searchhousename HSTORE;
2197 searchrankaddress INTEGER;
2198 searchpostcode TEXT;
2205 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2206 WHERE place_id = in_place_id
2207 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2209 IF for_place_id IS NULL THEN
2210 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2211 WHERE place_id = in_place_id
2212 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2215 IF for_place_id IS NULL THEN
2216 select parent_place_id, calculated_country_code, housenumber, rank_address, postcode, name, class, type from placex
2217 WHERE place_id = in_place_id and rank_address = 30
2218 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2221 IF for_place_id IS NULL THEN
2222 for_place_id := in_place_id;
2223 select calculated_country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2224 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2227 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2230 hadcountry := false;
2232 select placex.place_id, osm_type, osm_id,
2233 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2234 class, type, admin_level, true as fromarea, true as isaddress,
2235 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2236 0 as distance, calculated_country_code
2238 where place_id = for_place_id
2240 --RAISE WARNING '%',location;
2241 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2242 searchcountrycode := location.calculated_country_code;
2244 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2245 location.isaddress := FALSE;
2247 IF location.rank_address = 4 AND location.isaddress THEN
2250 IF location.rank_address < 4 AND NOT hadcountry THEN
2251 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2252 IF countryname IS NOT NULL THEN
2253 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2254 RETURN NEXT countrylocation;
2257 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2258 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2259 location.distance)::addressline;
2260 RETURN NEXT countrylocation;
2261 found := location.rank_address;
2265 select placex.place_id, osm_type, osm_id,
2266 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2267 class, type, admin_level, fromarea, isaddress,
2268 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,
2269 distance,calculated_country_code
2270 from place_addressline join placex on (address_place_id = placex.place_id)
2271 where place_addressline.place_id = for_place_id
2272 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2273 and address_place_id != for_place_id
2274 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2275 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2277 --RAISE WARNING '%',location;
2278 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2279 searchcountrycode := location.calculated_country_code;
2281 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2282 location.isaddress := FALSE;
2284 IF location.rank_address = 4 AND location.isaddress THEN
2287 IF location.rank_address < 4 AND NOT hadcountry THEN
2288 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2289 IF countryname IS NOT NULL THEN
2290 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2291 RETURN NEXT countrylocation;
2294 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2295 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2296 location.distance)::addressline;
2297 RETURN NEXT countrylocation;
2298 found := location.rank_address;
2302 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2303 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2304 IF countryname IS NOT NULL THEN
2305 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2306 RETURN NEXT location;
2310 IF searchcountrycode IS NOT NULL THEN
2311 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2312 RETURN NEXT location;
2315 IF searchhousename IS NOT NULL THEN
2316 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2317 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2318 RETURN NEXT location;
2321 IF searchhousenumber IS NOT NULL THEN
2322 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2323 RETURN NEXT location;
2326 IF searchpostcode IS NOT NULL THEN
2327 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2328 RETURN NEXT location;
2336 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2339 result place_boundingbox;
2340 numfeatures integer;
2342 select * from place_boundingbox into result where place_id = search_place_id;
2343 IF result.place_id IS NULL THEN
2344 -- remove isaddress = true because if there is a matching polygon it always wins
2345 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2346 insert into place_boundingbox select place_id,
2347 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2348 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2349 numfeatures, ST_Area(geometry),
2350 geometry as area from location_area where place_id = search_place_id;
2351 select * from place_boundingbox into result where place_id = search_place_id;
2353 IF result.place_id IS NULL THEN
2355 insert into place_boundingbox select address_place_id,
2356 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2357 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2358 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2359 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2360 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)
2361 where address_place_id = search_place_id
2362 -- and (isaddress = true OR place_id = search_place_id)
2363 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2364 group by address_place_id limit 1;
2365 select * from place_boundingbox into result where place_id = search_place_id;
2372 -- don't do the operation if it would be slow
2373 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2376 result place_boundingbox;
2377 numfeatures integer;
2380 select * from place_boundingbox into result where place_id = search_place_id;
2381 IF result IS NULL AND rank > 14 THEN
2382 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2383 insert into place_boundingbox select place_id,
2384 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2385 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2386 numfeatures, ST_Area(geometry),
2387 geometry as area from location_area where place_id = search_place_id;
2388 select * from place_boundingbox into result where place_id = search_place_id;
2390 IF result IS NULL THEN
2391 select rank_search from placex where place_id = search_place_id into rank;
2394 insert into place_boundingbox select address_place_id,
2395 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2396 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2397 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2398 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2399 from place_addressline join placex using (place_id)
2400 where address_place_id = search_place_id
2401 and (isaddress = true OR place_id = search_place_id)
2402 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2403 group by address_place_id limit 1;
2404 select * from place_boundingbox into result where place_id = search_place_id;
2412 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2415 result place_boundingbox;
2416 numfeatures integer;
2420 housenumber = place.housenumber,
2421 street = place.street,
2423 postcode = place.postcode,
2424 country_code = place.country_code,
2425 parent_place_id = null
2427 where placex.place_id = search_place_id
2428 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2429 and place.class = placex.class and place.type = placex.type;
2430 update placex set indexed_status = 2 where place_id = search_place_id;
2431 update placex set indexed_status = 0 where place_id = search_place_id;
2437 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2443 ELSEIF rank < 4 THEN
2445 ELSEIF rank < 8 THEN
2447 ELSEIF rank < 12 THEN
2449 ELSEIF rank < 16 THEN
2451 ELSEIF rank = 16 THEN
2453 ELSEIF rank = 17 THEN
2454 RETURN 'Town / Island';
2455 ELSEIF rank = 18 THEN
2456 RETURN 'Village / Hamlet';
2457 ELSEIF rank = 20 THEN
2459 ELSEIF rank = 21 THEN
2460 RETURN 'Postcode Area';
2461 ELSEIF rank = 22 THEN
2462 RETURN 'Croft / Farm / Locality / Islet';
2463 ELSEIF rank = 23 THEN
2464 RETURN 'Postcode Area';
2465 ELSEIF rank = 25 THEN
2466 RETURN 'Postcode Point';
2467 ELSEIF rank = 26 THEN
2468 RETURN 'Street / Major Landmark';
2469 ELSEIF rank = 27 THEN
2470 RETURN 'Minory Street / Path';
2471 ELSEIF rank = 28 THEN
2472 RETURN 'House / Building';
2474 RETURN 'Other: '||rank;
2481 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2487 ELSEIF rank < 2 THEN
2489 ELSEIF rank < 4 THEN
2491 ELSEIF rank = 5 THEN
2493 ELSEIF rank < 8 THEN
2495 ELSEIF rank < 12 THEN
2497 ELSEIF rank < 16 THEN
2499 ELSEIF rank = 16 THEN
2501 ELSEIF rank = 17 THEN
2502 RETURN 'Town / Village / Hamlet';
2503 ELSEIF rank = 20 THEN
2505 ELSEIF rank = 21 THEN
2506 RETURN 'Postcode Area';
2507 ELSEIF rank = 22 THEN
2508 RETURN 'Croft / Farm / Locality / Islet';
2509 ELSEIF rank = 23 THEN
2510 RETURN 'Postcode Area';
2511 ELSEIF rank = 25 THEN
2512 RETURN 'Postcode Point';
2513 ELSEIF rank = 26 THEN
2514 RETURN 'Street / Major Landmark';
2515 ELSEIF rank = 27 THEN
2516 RETURN 'Minory Street / Path';
2517 ELSEIF rank = 28 THEN
2518 RETURN 'House / Building';
2520 RETURN 'Other: '||rank;
2527 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2534 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2535 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2542 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2550 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2552 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2553 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2555 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2563 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2564 in_endnumber INTEGER, interpolationtype TEXT,
2565 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2569 startnumber INTEGER;
2574 numberrange INTEGER;
2575 rangestartnumber INTEGER;
2576 place_centroid GEOMETRY;
2577 out_partition INTEGER;
2578 out_parent_place_id BIGINT;
2580 address_street_word_id INTEGER;
2584 IF in_endnumber > in_startnumber THEN
2585 startnumber = in_startnumber;
2586 endnumber = in_endnumber;
2588 startnumber = in_endnumber;
2589 endnumber = in_startnumber;
2592 numberrange := endnumber - startnumber;
2593 rangestartnumber := startnumber;
2595 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2596 startnumber := startnumber + 1;
2599 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2601 ELSE -- everything else assumed to be 'all'
2606 -- Filter out really broken tiger data
2607 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2608 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2609 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2610 ST_length(linegeo)/(numberrange::float/stepsize::float);
2614 place_centroid := ST_Centroid(linegeo);
2615 out_partition := get_partition(place_centroid, 'us');
2616 out_parent_place_id := null;
2618 address_street_word_id := get_name_id(make_standard_name(in_street));
2619 IF address_street_word_id IS NOT NULL THEN
2620 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2621 out_parent_place_id := location.place_id;
2625 IF out_parent_place_id IS NULL THEN
2626 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP
2627 out_parent_place_id := location.place_id;
2631 IF out_parent_place_id IS NULL THEN
2632 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2633 out_parent_place_id := location.place_id;
2638 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2639 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2640 values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode,
2641 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2642 newpoints := newpoints + 1;
2650 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2651 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2656 place_centroid GEOMETRY;
2657 out_partition INTEGER;
2658 out_parent_place_id BIGINT;
2660 address_street_word_id INTEGER;
2665 place_centroid := ST_Centroid(pointgeo);
2666 out_partition := get_partition(place_centroid, in_countrycode);
2667 out_parent_place_id := null;
2669 address_street_word_id := get_name_id(make_standard_name(in_street));
2670 IF address_street_word_id IS NOT NULL THEN
2671 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2672 out_parent_place_id := location.place_id;
2676 IF out_parent_place_id IS NULL THEN
2677 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2678 out_parent_place_id := location.place_id;
2682 out_postcode := in_postcode;
2683 IF out_postcode IS NULL THEN
2684 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2686 IF out_postcode IS NULL THEN
2687 out_postcode := getNearestPostcode(out_partition, place_centroid);
2691 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2692 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2693 newpoints := newpoints + 1;
2700 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2707 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2708 IF members[i+1] = member THEN
2709 result := result || members[i];
2718 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2724 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2725 IF members[i+1] = ANY(memberLabels) THEN
2726 RETURN NEXT members[i];
2735 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2736 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2738 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2739 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
2740 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2741 ), '') AS bytea), 'UTF8');
2743 LANGUAGE SQL IMMUTABLE STRICT;
2745 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2749 RETURN decode_url_part(p);
2751 WHEN others THEN return null;
2754 LANGUAGE plpgsql IMMUTABLE;
2756 DROP TYPE wikipedia_article_match CASCADE;
2757 create type wikipedia_article_match as (
2763 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2769 wiki_article_title TEXT;
2770 wiki_article_language TEXT;
2771 result wikipedia_article_match;
2773 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'];
2775 WHILE langs[i] IS NOT NULL LOOP
2776 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2777 IF wiki_article is not null THEN
2778 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2779 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2780 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2781 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2782 wiki_article := replace(wiki_article,' ','_');
2783 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2784 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2785 wiki_article_title := trim(wiki_article);
2786 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;
2788 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2791 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2792 from wikipedia_article
2793 where language = wiki_article_language and
2794 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2796 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2797 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2798 where wikipedia_redirect.language = wiki_article_language and
2799 (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'\\',''))
2800 order by importance desc limit 1 INTO result;
2802 IF result.language is not null THEN
2813 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2814 RETURNS SETOF GEOMETRY
2828 remainingdepth INTEGER;
2833 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2835 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2836 RETURN NEXT geometry;
2840 remainingdepth := maxdepth - 1;
2841 area := ST_AREA(geometry);
2842 IF remainingdepth < 1 OR area < maxarea THEN
2843 RETURN NEXT geometry;
2847 xmin := st_xmin(geometry);
2848 xmax := st_xmax(geometry);
2849 ymin := st_ymin(geometry);
2850 ymax := st_ymax(geometry);
2851 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2853 -- if the geometry completely covers the box don't bother to slice any more
2854 IF ST_AREA(secbox) = area THEN
2855 RETURN NEXT geometry;
2859 xmid := (xmin+xmax)/2;
2860 ymid := (ymin+ymax)/2;
2863 FOR seg IN 1..4 LOOP
2866 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2869 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2872 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2875 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2878 IF st_intersects(geometry, secbox) THEN
2879 secgeo := st_intersection(geometry, secbox);
2880 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2881 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2882 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2884 RETURN NEXT geo.geom;
2896 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2897 RETURNS SETOF GEOMETRY
2902 -- 10000000000 is ~~ 1x1 degree
2903 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2904 RETURN NEXT geo.geom;