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;
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(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
72 -- RAISE WARNING '%',osmid;
77 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
78 NEWgeometry := ST_buffer(NEWgeometry,0);
79 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
83 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
86 LANGUAGE plpgsql IMMUTABLE;
88 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
89 AS '{modulepath}/nominatim.so', 'transliteration'
90 LANGUAGE c IMMUTABLE STRICT;
92 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
93 AS '{modulepath}/nominatim.so', 'gettokenstring'
94 LANGUAGE c IMMUTABLE STRICT;
96 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
101 o := gettokenstring(transliteration(name));
102 RETURN trim(substr(o,1,length(o)));
105 LANGUAGE 'plpgsql' IMMUTABLE;
107 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
112 return_word_id INTEGER;
114 lookup_token := trim(lookup_word);
115 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
116 IF return_word_id IS NULL THEN
117 return_word_id := nextval('seq_word');
118 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);
120 RETURN return_word_id;
125 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
130 return_word_id INTEGER;
132 lookup_token := ' '||trim(lookup_word);
133 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
134 IF return_word_id IS NULL THEN
135 return_word_id := nextval('seq_word');
136 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
138 RETURN return_word_id;
143 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
148 return_word_id INTEGER;
150 lookup_token := ' '||trim(lookup_word);
151 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
152 IF return_word_id IS NULL THEN
153 return_word_id := nextval('seq_word');
154 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
156 RETURN return_word_id;
161 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
174 RETURN return_word_id;
179 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
184 return_word_id INTEGER;
186 lookup_token := lookup_class||'='||lookup_type;
187 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
188 IF return_word_id IS NULL THEN
189 return_word_id := nextval('seq_word');
190 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
192 RETURN return_word_id;
197 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
202 return_word_id INTEGER;
204 lookup_token := lookup_class||'='||lookup_type;
205 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
206 RETURN return_word_id;
211 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
216 return_word_id INTEGER;
218 lookup_token := ' '||trim(lookup_word);
219 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;
220 IF return_word_id IS NULL THEN
221 return_word_id := nextval('seq_word');
222 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
224 RETURN return_word_id;
229 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
234 nospace_lookup_token TEXT;
235 return_word_id INTEGER;
237 lookup_token := ' '||trim(lookup_word);
238 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
239 IF return_word_id IS NULL THEN
240 return_word_id := nextval('seq_word');
241 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);
242 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
243 -- IF ' '||nospace_lookup_token != lookup_token THEN
244 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
247 RETURN return_word_id;
252 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
257 RETURN getorcreate_name_id(lookup_word, '');
262 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
267 return_word_id INTEGER;
269 lookup_token := trim(lookup_word);
270 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
271 RETURN return_word_id;
274 LANGUAGE plpgsql IMMUTABLE;
276 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
281 return_word_id INTEGER;
283 lookup_token := ' '||trim(lookup_word);
284 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
285 RETURN return_word_id;
288 LANGUAGE plpgsql IMMUTABLE;
290 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
297 IF array_upper(a, 1) IS NULL THEN
300 IF array_upper(b, 1) IS NULL THEN
304 FOR i IN 1..array_upper(b, 1) LOOP
305 IF NOT (ARRAY[b[i]] <@ r) THEN
312 LANGUAGE plpgsql IMMUTABLE;
314 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
324 result := '{}'::INTEGER[];
326 FOR item IN SELECT (each(src)).* LOOP
328 s := make_standard_name(item.value);
330 w := getorcreate_name_id(s, item.value);
332 IF not(ARRAY[w] <@ result) THEN
333 result := result || w;
336 words := string_to_array(s, ' ');
337 IF array_upper(words, 1) IS NOT NULL THEN
338 FOR j IN 1..array_upper(words, 1) LOOP
339 IF (words[j] != '') THEN
340 w = getorcreate_word_id(words[j]);
341 IF NOT (ARRAY[w] <@ result) THEN
342 result := result || w;
348 words := regexp_split_to_array(item.value, E'[,;()]');
349 IF array_upper(words, 1) != 1 THEN
350 FOR j IN 1..array_upper(words, 1) LOOP
351 s := make_standard_name(words[j]);
353 w := getorcreate_word_id(s);
354 IF NOT (ARRAY[w] <@ result) THEN
355 result := result || w;
361 s := regexp_replace(item.value, '市$', '');
362 IF s != item.value THEN
363 s := make_standard_name(s);
365 w := getorcreate_name_id(s, item.value);
366 IF NOT (ARRAY[w] <@ result) THEN
367 result := result || w;
377 LANGUAGE plpgsql IMMUTABLE;
379 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
389 result := '{}'::INTEGER[];
391 s := make_standard_name(src);
392 w := getorcreate_name_id(s, src);
394 IF NOT (ARRAY[w] <@ result) THEN
395 result := result || w;
398 words := string_to_array(s, ' ');
399 IF array_upper(words, 1) IS NOT NULL THEN
400 FOR j IN 1..array_upper(words, 1) LOOP
401 IF (words[j] != '') THEN
402 w = getorcreate_word_id(words[j]);
403 IF NOT (ARRAY[w] <@ result) THEN
404 result := result || w;
410 words := regexp_split_to_array(src, E'[,;()]');
411 IF array_upper(words, 1) != 1 THEN
412 FOR j IN 1..array_upper(words, 1) LOOP
413 s := make_standard_name(words[j]);
415 w := getorcreate_word_id(s);
416 IF NOT (ARRAY[w] <@ result) THEN
417 result := result || w;
423 s := regexp_replace(src, '市$', '');
425 s := make_standard_name(s);
427 w := getorcreate_name_id(s, src);
428 IF NOT (ARRAY[w] <@ result) THEN
429 result := result || w;
437 LANGUAGE plpgsql IMMUTABLE;
439 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
446 IF (wordscores is null OR words is null) THEN
451 FOR idxword in 1 .. array_upper(words, 1) LOOP
452 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
453 IF wordscores[idxscores].word = words[idxword] THEN
454 result := result + wordscores[idxscores].score;
462 LANGUAGE plpgsql IMMUTABLE;
464 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
467 place_centre GEOMETRY;
470 place_centre := ST_Centroid(place);
472 --RAISE WARNING 'start: %', ST_AsText(place_centre);
474 -- Try for a OSM polygon first
475 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_contains(geometry, place_centre) limit 1
477 RETURN nearcountry.country_code;
480 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
482 -- Try for OSM fallback data
483 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
485 RETURN nearcountry.country_code;
488 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
490 -- Natural earth data (first fallback)
491 FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
493 RETURN nearcountry.country_code;
496 -- Natural earth data (first fallback)
497 FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1
499 RETURN nearcountry.country_code;
502 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
504 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
505 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
507 RETURN nearcountry.country_code;
510 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
512 -- Still not in a country - try nearest within ~12 miles of a country
513 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
514 order by st_distance(geometry, place) limit 1
516 RETURN nearcountry.country_code;
522 LANGUAGE plpgsql IMMUTABLE;
524 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
529 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
531 RETURN nearcountry.country_code;
533 RETURN get_country_code(place);
536 LANGUAGE plpgsql IMMUTABLE;
538 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
543 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
545 RETURN lower(nearcountry.country_default_language_code);
550 LANGUAGE plpgsql IMMUTABLE;
552 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
555 place_centre GEOMETRY;
558 FOR nearcountry IN select partition from country_name where country_code = in_country_code
560 RETURN nearcountry.partition;
565 LANGUAGE plpgsql IMMUTABLE;
567 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
571 DELETE FROM location_area where place_id = OLD_place_id;
572 -- TODO:location_area
578 CREATE OR REPLACE FUNCTION add_location(
580 country_code varchar(2),
584 rank_address INTEGER,
605 IF rank_search > 25 THEN
606 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
609 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
611 x := deleteLocationArea(partition, place_id);
614 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
617 centroid := ST_Centroid(geometry);
619 xmin := floor(st_xmin(geometry));
620 xmax := ceil(st_xmax(geometry));
621 ymin := floor(st_ymin(geometry));
622 ymax := ceil(st_ymax(geometry));
624 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
625 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
627 -- RAISE WARNING 'Spliting geometry: % to %, % to %', xmin, xmax, ymin, ymax;
628 FOR lon IN xmin..(xmax-1) LOOP
629 FOR lat IN ymin..(ymax-1) LOOP
630 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
631 IF st_intersects(geometry, secbox) THEN
632 secgeo := st_intersection(geometry, secbox);
633 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
634 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
641 ELSEIF rank_search < 26 THEN
644 IF rank_address = 0 THEN
646 ELSEIF rank_search <= 14 THEN
648 ELSEIF rank_search <= 15 THEN
650 ELSEIF rank_search <= 16 THEN
652 ELSEIF rank_search <= 17 THEN
654 ELSEIF rank_search <= 21 THEN
656 ELSEIF rank_search = 25 THEN
660 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
662 secgeo := ST_Buffer(geometry, diameter);
663 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
668 secgeo := ST_Buffer(geometry, 0.0002);
669 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
672 secgeo := ST_Buffer(geometry, 0.001);
673 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
682 CREATE OR REPLACE FUNCTION update_location(
685 place_country_code varchar(2),
688 rank_address INTEGER,
696 b := deleteLocationArea(partition, place_id);
697 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
698 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
703 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
714 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
715 FOR childplace IN select * from search_name,place_addressline
716 where address_place_id = parent_place_id
717 and search_name.place_id = place_addressline.place_id
719 delete from search_name where place_id = childplace.place_id;
720 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
721 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
723 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
724 childplace.name_vector := childplace.name_vector || to_add;
726 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
727 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
728 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
736 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
739 newkeywords INTEGER[];
740 addedkeywords INTEGER[];
741 removedkeywords INTEGER[];
745 newkeywords := make_keywords(name);
746 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
747 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
748 where place_id = OLD_place_id into addedkeywords, removedkeywords;
750 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
752 IF #removedkeywords > 0 THEN
753 -- abort due to tokens removed
757 IF #addedkeywords > 0 THEN
758 -- short circuit - no changes
762 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
763 RETURN search_name_add_words(OLD_place_id, addedkeywords);
769 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
781 orginalstartnumber INTEGER;
782 originalnumberrange INTEGER;
785 search_place_id BIGINT;
788 havefirstpoint BOOLEAN;
792 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
794 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
795 select nodes from planet_osm_ways where id = wayid INTO waynodes;
796 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
797 IF array_upper(waynodes, 1) IS NOT NULL THEN
799 havefirstpoint := false;
801 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
803 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
804 IF search_place_id IS NULL THEN
805 -- null record of right type
806 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
807 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
809 select * from placex where place_id = search_place_id INTO nextnode;
812 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
814 IF havefirstpoint THEN
816 -- add point to the line string
817 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
818 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
820 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
822 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
824 IF startnumber != endnumber THEN
826 linestr := linestr || ')';
827 --RAISE WARNING 'linestr %',linestr;
828 linegeo := ST_GeomFromText(linestr,4326);
829 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
830 IF (startnumber > endnumber) THEN
831 housenum := endnumber;
832 endnumber := startnumber;
833 startnumber := housenum;
834 linegeo := ST_Reverse(linegeo);
836 orginalstartnumber := startnumber;
837 originalnumberrange := endnumber - startnumber;
839 -- Too much broken data worldwide for this test to be worth using
840 -- IF originalnumberrange > 500 THEN
841 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
844 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
845 startnumber := startnumber + 1;
848 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
849 startnumber := startnumber + 2;
851 ELSE -- everything else assumed to be 'all'
852 startnumber := startnumber + 1;
856 endnumber := endnumber - 1;
857 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
858 FOR housenum IN startnumber..endnumber BY stepsize LOOP
859 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
860 -- ideally postcodes should move up to the way
861 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
862 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
863 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
864 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));
865 newpoints := newpoints + 1;
866 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
869 havefirstpoint := false;
873 IF NOT havefirstpoint THEN
874 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
875 IF startnumber IS NOT NULL AND startnumber > 0 THEN
876 havefirstpoint := true;
877 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
878 prevnode := nextnode;
880 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
886 --RAISE WARNING 'interpolation points % ',newpoints;
893 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
899 country_code VARCHAR(2);
900 default_language VARCHAR(10);
904 -- RAISE WARNING '%',NEW.osm_id;
907 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
908 -- RAISE WARNING 'bad highway %',NEW.osm_id;
911 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
912 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
916 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
917 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
918 -- RAISE WARNING 'invalid geometry %',NEW.osm_id;
922 IF NEW.osm_type = 'R' THEN
923 -- invalid multipolygons can crash postgis, don't even bother to try!
926 NEW.geometry := ST_buffer(NEW.geometry,0);
927 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
928 -- RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
933 NEW.place_id := nextval('seq_place');
934 NEW.indexed_status := 1; --STATUS_NEW
936 IF NEW.rank_search >= 4 THEN
937 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
939 NEW.country_code := NULL;
942 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
943 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
945 -- copy 'name' to or from the default language (if there is a default language)
946 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
947 default_language := get_country_language_code(NEW.country_code);
948 IF default_language IS NOT NULL THEN
949 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
950 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
951 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
952 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
957 IF NEW.admin_level > 15 THEN
958 NEW.admin_level := 15;
961 IF NEW.housenumber IS NOT NULL THEN
962 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
965 IF NEW.osm_type = 'X' THEN
966 -- E'X'ternal records should already be in the right format so do nothing
968 NEW.rank_search := 30;
969 NEW.rank_address := NEW.rank_search;
971 -- By doing in postgres we have the country available to us - currently only used for postcode
972 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
974 IF NEW.postcode IS NULL THEN
975 -- most likely just a part of a multipolygon postcode boundary, throw it away
979 NEW.name := 'ref'=>NEW.postcode;
981 IF NEW.country_code = 'gb' THEN
983 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
984 NEW.rank_search := 25;
985 NEW.rank_address := 5;
986 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
987 NEW.rank_search := 23;
988 NEW.rank_address := 5;
989 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
990 NEW.rank_search := 21;
991 NEW.rank_address := 5;
994 ELSEIF NEW.country_code = 'de' THEN
996 IF NEW.postcode ~ '^([0-9]{5})$' THEN
997 NEW.rank_search := 21;
998 NEW.rank_address := 11;
1002 -- Guess at the postcode format and coverage (!)
1003 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1004 NEW.rank_search := 21;
1005 NEW.rank_address := 11;
1007 -- Does it look splitable into and area and local code?
1008 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1010 IF postcode IS NOT NULL THEN
1011 NEW.rank_search := 25;
1012 NEW.rank_address := 11;
1013 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1014 NEW.rank_search := 21;
1015 NEW.rank_address := 11;
1020 ELSEIF NEW.class = 'place' THEN
1021 IF NEW.type in ('continent') THEN
1022 NEW.rank_search := 2;
1023 NEW.rank_address := NEW.rank_search;
1024 ELSEIF NEW.type in ('sea') THEN
1025 NEW.rank_search := 2;
1026 NEW.rank_address := 0;
1027 ELSEIF NEW.type in ('country') THEN
1028 NEW.rank_search := 4;
1029 NEW.rank_address := NEW.rank_search;
1030 ELSEIF NEW.type in ('state') THEN
1031 NEW.rank_search := 8;
1032 NEW.rank_address := NEW.rank_search;
1033 ELSEIF NEW.type in ('region') THEN
1034 NEW.rank_search := 18; -- dropped from previous value of 10
1035 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1036 ELSEIF NEW.type in ('county') THEN
1037 NEW.rank_search := 12;
1038 NEW.rank_address := NEW.rank_search;
1039 ELSEIF NEW.type in ('city') THEN
1040 NEW.rank_search := 16;
1041 NEW.rank_address := NEW.rank_search;
1042 ELSEIF NEW.type in ('island') THEN
1043 NEW.rank_search := 17;
1044 NEW.rank_address := 0;
1045 ELSEIF NEW.type in ('town') THEN
1046 NEW.rank_search := 18;
1047 NEW.rank_address := 16;
1048 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1049 NEW.rank_search := 19;
1050 NEW.rank_address := 16;
1051 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1052 NEW.rank_search := 18;
1053 NEW.rank_address := 17;
1054 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1055 NEW.rank_search := 17;
1056 NEW.rank_address := 18;
1057 ELSEIF NEW.type in ('moor') THEN
1058 NEW.rank_search := 17;
1059 NEW.rank_address := 0;
1060 ELSEIF NEW.type in ('national_park') THEN
1061 NEW.rank_search := 18;
1062 NEW.rank_address := 18;
1063 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1064 NEW.rank_search := 20;
1065 NEW.rank_address := NEW.rank_search;
1066 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1067 NEW.rank_search := 20;
1068 NEW.rank_address := 0;
1069 -- Irish townlands, tagged as place=locality and locality=townland
1070 IF (NEW.extratags -> 'locality') = 'townland' THEN
1071 NEW.rank_address := 20;
1073 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1074 NEW.rank_search := 22;
1075 NEW.rank_address := 22;
1076 ELSEIF NEW.type in ('airport','street') THEN
1077 NEW.rank_search := 26;
1078 NEW.rank_address := NEW.rank_search;
1079 ELSEIF NEW.type in ('house','building') THEN
1080 NEW.rank_search := 30;
1081 NEW.rank_address := NEW.rank_search;
1082 ELSEIF NEW.type in ('houses') THEN
1083 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1084 -- insert new point into place for each derived building
1085 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1086 NEW.rank_search := 28;
1087 NEW.rank_address := 0;
1090 ELSEIF NEW.class = 'boundary' THEN
1091 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1092 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1095 NEW.rank_search := NEW.admin_level * 2;
1096 NEW.rank_address := NEW.rank_search;
1097 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1098 NEW.rank_search := 22;
1099 NEW.rank_address := NEW.rank_search;
1100 -- any feature more than 5 square miles is probably worth indexing
1101 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1102 NEW.rank_search := 22;
1103 NEW.rank_address := NEW.rank_search;
1104 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1105 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1106 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1108 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1110 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1112 ELSEIF NEW.class = 'waterway' THEN
1113 NEW.rank_address := 17;
1114 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
1115 NEW.rank_search := 27;
1116 NEW.rank_address := NEW.rank_search;
1117 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1118 NEW.rank_search := 26;
1119 NEW.rank_address := NEW.rank_search;
1120 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1121 NEW.rank_search := 4;
1122 NEW.rank_address := NEW.rank_search;
1123 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1125 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1126 NEW.rank_search := 18;
1127 NEW.rank_address := 0;
1132 IF NEW.rank_search > 30 THEN
1133 NEW.rank_search := 30;
1136 IF NEW.rank_address > 30 THEN
1137 NEW.rank_address := 30;
1140 IF (NEW.extratags -> 'capital') = 'yes' THEN
1141 NEW.rank_search := NEW.rank_search -1;
1144 -- Block import below rank 22
1145 -- IF NEW.rank_search > 22 THEN
1149 RETURN NEW; -- The following is not needed until doing diff updates, and slows the main index process down
1151 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1152 -- Performance: We just can't handle re-indexing for country level changes
1153 IF st_area(NEW.geometry) < 1 THEN
1154 -- mark items within the geometry for re-indexing
1155 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1157 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1158 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1159 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);
1160 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1161 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);
1164 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1166 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1167 IF NEW.type='postcode' THEN
1169 ELSEIF NEW.rank_search < 16 THEN
1171 ELSEIF NEW.rank_search < 18 THEN
1173 ELSEIF NEW.rank_search < 20 THEN
1175 ELSEIF NEW.rank_search = 21 THEN
1177 ELSEIF NEW.rank_search < 24 THEN
1179 ELSEIF NEW.rank_search < 26 THEN
1180 diameter := 0.002; -- 100 to 200 meters
1181 ELSEIF NEW.rank_search < 28 THEN
1182 diameter := 0.001; -- 50 to 100 meters
1184 IF diameter > 0 THEN
1185 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1186 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);
1191 -- add to tables for special search
1192 -- Note: won't work on initial import because the classtype tables
1193 -- do not yet exist. It won't hurt either.
1194 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1195 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1197 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1198 USING NEW.place_id, ST_Centroid(NEW.geometry);
1202 -- IF NEW.rank_search < 26 THEN
1203 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1212 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1217 place_centroid GEOMETRY;
1219 search_maxdistance FLOAT[];
1220 search_mindistance FLOAT[];
1221 address_havelevel BOOLEAN[];
1222 -- search_scores wordscore[];
1223 -- search_scores_pos INTEGER;
1230 relation_members TEXT[];
1232 linkedplacex RECORD;
1233 search_diameter FLOAT;
1234 search_prevdiameter FLOAT;
1235 search_maxrank INTEGER;
1236 address_maxrank INTEGER;
1237 address_street_word_id INTEGER;
1238 parent_place_id_rank BIGINT;
1243 location_rank_search INTEGER;
1244 location_distance FLOAT;
1248 default_language TEXT;
1249 name_vector INTEGER[];
1250 nameaddress_vector INTEGER[];
1252 linked_node_id BIGINT;
1257 --RAISE WARNING '%',NEW.place_id;
1258 --RAISE WARNING '%', NEW;
1260 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1261 -- Silently do nothing
1266 IF OLD.indexed_status = 100 THEN
1267 delete from placex where place_id = OLD.place_id;
1271 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1273 NEW.indexed_date = now();
1275 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1276 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1280 IF OLD.indexed_status > 1 THEN
1281 result := deleteSearchName(NEW.partition, NEW.place_id);
1282 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1283 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1284 result := deleteRoad(NEW.partition, NEW.place_id);
1285 result := deleteLocationArea(NEW.partition, NEW.place_id);
1286 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1289 -- reclaculate country and partition (should probably have a country_code and calculated_country_code as seperate fields)
1290 IF NEW.rank_search >= 4 THEN
1291 SELECT country_code from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO NEW.country_code;
1292 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1294 NEW.country_code := NULL;
1296 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
1297 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1299 -- Adding ourselves to the list simplifies address calculations later
1300 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1302 -- What level are we searching from
1303 search_maxrank := NEW.rank_search;
1305 -- Speed up searches - just use the centroid of the feature
1306 -- cheaper but less acurate
1307 place_centroid := ST_Centroid(NEW.geometry);
1308 NEW.centroid := null;
1310 -- Thought this wasn't needed but when we add new languages to the country_name table
1311 -- we need to update the existing names
1312 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1313 default_language := get_country_language_code(NEW.country_code);
1314 IF default_language IS NOT NULL THEN
1315 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1316 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1317 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1318 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1323 -- Initialise the name vector using our name
1324 name_vector := make_keywords(NEW.name);
1325 nameaddress_vector := '{}'::int[];
1327 -- some tag combinations add a special id for search
1328 tagpairid := get_tagpair(NEW.class,NEW.type);
1329 IF tagpairid IS NOT NULL THEN
1330 name_vector := name_vector + tagpairid;
1334 address_havelevel[i] := false;
1337 NEW.importance := null;
1338 select language||':'||title,importance from get_wikipedia_match(NEW.extratags) INTO NEW.wikipedia,NEW.importance;
1339 IF NEW.importance IS NULL THEN
1340 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;
1343 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1345 -- For low level elements we inherit from our parent road
1346 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1348 --RAISE WARNING 'finding street for %', NEW;
1350 NEW.parent_place_id := null;
1352 -- to do that we have to find our parent road
1353 -- Copy data from linked items (points on ways, addr:street links, relations)
1354 -- Note that addr:street links can only be indexed once the street itself is indexed
1355 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1357 -- Is this node part of a relation?
1358 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1360 -- At the moment we only process one type of relation - associatedStreet
1361 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1362 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1363 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1364 --RAISE WARNING 'node in relation %',relation;
1365 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1366 and rank_search = 26 INTO NEW.parent_place_id;
1372 --RAISE WARNING 'x1';
1373 -- Is this node part of a way?
1374 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1375 --RAISE WARNING '%', way;
1376 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1378 --RAISE WARNING '%', location;
1379 -- Way IS a road then we are on it - that must be our road
1380 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1381 --RAISE WARNING 'node in way that is a street %',location;
1382 NEW.parent_place_id := location.place_id;
1385 -- Is the WAY part of a relation
1386 IF NEW.parent_place_id IS NULL THEN
1387 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1389 -- At the moment we only process one type of relation - associatedStreet
1390 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1391 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1392 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1393 --RAISE WARNING 'node in way that is in a relation %',relation;
1394 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1395 and rank_search = 26 INTO NEW.parent_place_id;
1402 -- If the way contains an explicit name of a street copy it
1403 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1404 --RAISE WARNING 'node in way that has a streetname %',location;
1405 NEW.street := location.street;
1408 -- If this way is a street interpolation line then it is probably as good as we are going to get
1409 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1410 -- Try and find a way that is close roughly parellel to this line
1411 FOR relation IN SELECT place_id FROM placex
1412 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1413 and st_geometrytype(location.geometry) in ('ST_LineString')
1414 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1415 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1416 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1418 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1419 NEW.parent_place_id := relation.place_id;
1428 --RAISE WARNING 'x2';
1430 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1431 -- Is this way part of a relation?
1432 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1434 -- At the moment we only process one type of relation - associatedStreet
1435 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1436 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1437 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1438 --RAISE WARNING 'way that is in a relation %',relation;
1439 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1440 and rank_search = 26 INTO NEW.parent_place_id;
1447 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1449 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1450 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1451 IF address_street_word_id IS NOT NULL THEN
1452 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1453 NEW.parent_place_id := location.place_id;
1458 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1459 -- Still nothing, just use the nearest road
1460 IF NEW.parent_place_id IS NULL THEN
1461 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1462 NEW.parent_place_id := location.place_id;
1467 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1469 -- If we didn't find any road fallback to standard method
1470 IF NEW.parent_place_id IS NOT NULL THEN
1472 -- Add the street to the address as zero distance to force to front of list
1473 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1474 address_havelevel[26] := true;
1476 -- Import address details from parent, reclculating distance in process
1477 -- 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
1478 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1479 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1481 -- Get the details of the parent road
1482 select * from search_name where place_id = NEW.parent_place_id INTO location;
1483 NEW.country_code := location.country_code;
1485 --RAISE WARNING '%', NEW.name;
1486 -- If there is no name it isn't searchable, don't bother to create a search record
1487 IF NEW.name is NULL THEN
1491 -- Merge address from parent
1492 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1494 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1495 -- Just be happy with inheriting from parent road only
1497 IF NEW.rank_search <= 25 THEN
1498 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1501 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1508 -- RAISE WARNING ' INDEXING: %',NEW;
1510 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1512 -- see if we have any special relation members
1513 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1515 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1517 select * from placex where osm_type = upper(substring(relMember.member,1,1))
1518 and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex;
1520 -- If we don't already have one use this as the centre point of the geometry
1521 IF NEW.centroid IS NULL THEN
1522 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1525 -- merge in the label name, re-init word vector
1526 NEW.name := linkedPlacex.name || NEW.name;
1527 name_vector := make_keywords(NEW.name);
1529 -- merge in extra tags
1530 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1532 -- mark the linked place (excludes from search results)
1533 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1537 IF NEW.centroid IS NULL THEN
1539 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1541 select * from placex where osm_type = upper(substring(relMember.member,1,1))
1542 and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex;
1544 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1545 -- But that can be fixed by explicitly setting the label in the data
1546 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1547 AND NEW.rank_search = linkedPlacex.rank_search THEN
1549 -- If we don't already have one use this as the centre point of the geometry
1550 IF NEW.centroid IS NULL THEN
1551 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1554 -- merge in the name, re-init word vector
1555 NEW.name := linkedPlacex.name || NEW.name;
1556 name_vector := make_keywords(NEW.name);
1558 -- merge in extra tags
1559 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1561 -- mark the linked place (excludes from search results)
1562 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1564 -- keep a note of the node id in case we need it for wikipedia in a bit
1565 linked_node_id := linkedPlacex.osm_id;
1572 -- not found one yet? how about doing a name search
1573 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1575 FOR linkedPlacex IN select placex.* from placex WHERE
1576 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1577 AND placex.rank_search = NEW.rank_search
1578 AND placex.place_id != NEW.place_id
1579 AND placex.osm_type = 'N' AND placex.rank_search < 26
1580 AND st_contains(NEW.geometry, placex.geometry)
1583 -- If we don't already have one use this as the centre point of the geometry
1584 IF NEW.centroid IS NULL THEN
1585 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1588 -- merge in the name, re-init word vector
1589 NEW.name := linkedPlacex.name || NEW.name;
1590 name_vector := make_keywords(NEW.name);
1592 -- merge in extra tags
1593 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1595 -- mark the linked place (excludes from search results)
1596 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1598 -- keep a note of the node id in case we need it for wikipedia in a bit
1599 linked_node_id := linkedPlacex.osm_id;
1603 IF NEW.centroid IS NOT NULL THEN
1604 place_centroid := NEW.centroid;
1607 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1608 IF NEW.importance is null THEN
1609 select language||':'||title,importance from get_wikipedia_match(NEW.extratags) INTO NEW.wikipedia,NEW.importance;
1611 -- Still null? how about looking it up by the node id
1612 IF NEW.importance IS NULL THEN
1613 select language||':'||title,importance from wikipedia_article where osm_type = 'N' and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
1618 NEW.parent_place_id = 0;
1619 parent_place_id_rank = 0;
1621 -- convert isin to array of tokenids
1622 isin_tokens := '{}'::int[];
1623 IF NEW.isin IS NOT NULL THEN
1624 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1625 IF array_upper(isin, 1) IS NOT NULL THEN
1626 FOR i IN 1..array_upper(isin, 1) LOOP
1627 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1628 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1629 isin_tokens := isin_tokens || address_street_word_id;
1634 IF NEW.postcode IS NOT NULL THEN
1635 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1636 IF array_upper(isin, 1) IS NOT NULL THEN
1637 FOR i IN 1..array_upper(isin, 1) LOOP
1638 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1639 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1640 isin_tokens := isin_tokens || address_street_word_id;
1645 --RAISE WARNING 'ISIN: %', isin_tokens;
1647 -- Process area matches
1648 location_rank_search := 100;
1649 location_distance := 0;
1650 --RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1651 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1653 --RAISE WARNING ' AREA: %',location;
1655 IF location.rank_search < location_rank_search THEN
1656 location_rank_search := location.rank_search;
1657 location_distance := location.distance * 1.5;
1660 IF location.distance < location_distance OR NOT location.isguess THEN
1662 -- Add it to the list of search terms
1663 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1664 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1665 address_havelevel[location.rank_address] := true;
1667 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1669 IF location.rank_address > parent_place_id_rank THEN
1670 NEW.parent_place_id = location.place_id;
1671 parent_place_id_rank = location.rank_address;
1678 -- try using the isin value to find parent places
1679 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1680 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1681 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1683 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1685 --RAISE WARNING ' ISIN: %',location;
1687 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1688 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1689 address_havelevel[location.rank_address] := true;
1691 IF location.rank_address > parent_place_id_rank THEN
1692 NEW.parent_place_id = location.place_id;
1693 parent_place_id_rank = location.rank_address;
1701 -- for long ways we should add search terms for the entire length
1702 IF st_length(NEW.geometry) > 0.05 THEN
1704 location_rank_search := 100;
1705 location_distance := 0;
1707 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1709 IF location.rank_search < location_rank_search THEN
1710 location_rank_search := location.rank_search;
1711 location_distance := location.distance * 1.5;
1714 IF location.distance < location_distance THEN
1716 -- Add it to the list of search terms
1717 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1718 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1726 -- if we have a name add this to the name search table
1727 IF NEW.name IS NOT NULL THEN
1729 IF NEW.rank_search <= 25 THEN
1730 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1733 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1734 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1737 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1739 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1742 -- If we've not managed to pick up a better one - default centroid
1743 IF NEW.centroid IS NULL THEN
1744 NEW.centroid := place_centroid;
1754 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1761 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1762 update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1764 IF OLD.rank_address < 30 THEN
1766 -- mark everything linked to this place for re-indexing
1767 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1768 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1770 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1772 b := deleteRoad(OLD.partition, OLD.place_id);
1774 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1778 IF OLD.rank_address < 26 THEN
1779 b := deleteLocationArea(OLD.partition, OLD.place_id);
1782 IF OLD.name is not null THEN
1783 b := deleteSearchName(OLD.partition, OLD.place_id);
1786 DELETE FROM place_addressline where place_id = OLD.place_id;
1788 -- remove from tables for special search
1789 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1790 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1792 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1801 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1807 -- 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;
1818 -- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1825 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1830 existingplacex RECORD;
1831 existinggeometry GEOMETRY;
1832 existingplace_id BIGINT;
1837 IF FALSE and NEW.osm_type = 'R' THEN
1838 RAISE WARNING '-----------------------------------------------------------------------------------';
1839 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
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 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 country_name.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 -- RAISE WARNING 'Existing: %',existing.place_id;
1880 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1881 AND st_area(existing.geometry) > 0.02
1882 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1883 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1885 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1886 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1890 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1891 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1893 -- 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
1894 IF existing.osm_type IS NULL
1895 OR existingplacex.osm_type IS NULL
1896 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1897 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1898 OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1899 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1902 -- IF existing.osm_type IS NULL THEN
1903 -- RAISE WARNING 'no existing place';
1905 -- IF existingplacex.osm_type IS NULL THEN
1906 -- RAISE WARNING 'no existing placex %', existingplacex;
1909 -- RAISE WARNING 'delete and replace';
1911 IF existing.osm_type IS NOT NULL THEN
1912 -- RAISE WARNING 'insert delete % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)),existing;
1913 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1916 -- RAISE WARNING 'delete and replace2';
1918 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1919 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1920 street, isin, postcode, country_code, extratags, geometry)
1921 values (NEW.osm_type
1936 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1941 -- Various ways to do the update
1943 -- Debug, what's changed?
1945 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1946 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1948 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1949 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1951 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1952 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1954 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1955 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1957 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1958 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1960 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1961 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1965 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1966 IF existing.geometry::text != NEW.geometry::text
1967 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1968 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1971 -- Get the version of the geometry actually used (in placex table)
1972 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;
1974 -- Performance limit
1975 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1977 -- 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
1978 update placex set indexed_status = 2 where indexed_status = 0 and
1979 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1980 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1981 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1983 update placex set indexed_status = 2 where indexed_status = 0 and
1984 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1985 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1986 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1992 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1993 IF FALSE AND existingplacex.rank_search < 26
1994 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1995 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1996 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1997 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1998 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1999 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2002 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2004 IF st_area(NEW.geometry) < 0.5 THEN
2005 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2006 and placex.place_id = place_addressline.place_id and indexed_status = 0
2007 and (rank_search < 28 or name is not null);
2014 -- Anything else has changed - reindex the lot
2015 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2016 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2017 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2018 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2019 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2020 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2022 -- performance, can't take the load of re-indexing a whole country / huge area
2023 IF st_area(NEW.geometry) < 0.5 THEN
2024 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2025 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2032 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2033 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2034 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2035 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2036 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2037 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2038 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2039 OR existing.geometry::text != NEW.geometry::text
2044 housenumber = NEW.housenumber,
2045 street = NEW.street,
2047 postcode = NEW.postcode,
2048 country_code = NEW.country_code,
2049 extratags = NEW.extratags,
2050 geometry = NEW.geometry
2051 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2055 housenumber = NEW.housenumber,
2056 street = NEW.street,
2058 postcode = NEW.postcode,
2059 country_code = NEW.country_code,
2060 parent_place_id = null,
2061 extratags = NEW.extratags,
2063 geometry = NEW.geometry
2064 where place_id = existingplacex.place_id;
2066 -- now done as part of insert
2067 -- partition := get_partition(NEW.geometry, existingplacex.country_code);
2068 -- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
2072 -- Abort the add (we modified the existing place instead)
2076 $$ LANGUAGE plpgsql;
2078 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2085 IF name is null THEN
2089 search := languagepref;
2091 FOR j IN 1..array_upper(search, 1) LOOP
2092 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2093 return trim(name->search[j]);
2100 LANGUAGE plpgsql IMMUTABLE;
2102 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2105 searchnodes INTEGER[];
2110 searchnodes := '{}';
2111 FOR j IN 1..array_upper(way_ids, 1) LOOP
2113 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2115 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2116 searchnodes := searchnodes || location.nodes;
2121 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2124 LANGUAGE plpgsql IMMUTABLE;
2126 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2137 search := ARRAY['ref'];
2140 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2143 select rank_address,name,distance,length(name::text) as namelength
2144 from place_addressline join placex on (address_place_id = placex.place_id)
2145 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2146 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2148 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2149 FOR j IN 1..array_upper(search, 1) LOOP
2150 FOR k IN 1..array_upper(location.name, 1) LOOP
2151 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
2152 result[(100 - location.rank_address)] := trim(location.name[k].value);
2153 found := location.rank_address;
2160 RETURN array_to_string(result,', ');
2165 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2177 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2178 currresult := trim(get_name_by_language(location.name, languagepref));
2179 IF currresult != prevresult AND currresult IS NOT NULL THEN
2180 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2181 prevresult := currresult;
2185 RETURN array_to_string(result,', ');
2190 DROP TYPE addressline CASCADE;
2191 create type addressline as (
2198 admin_level INTEGER,
2201 rank_address INTEGER,
2205 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2208 for_place_id BIGINT;
2213 countrylocation RECORD;
2214 searchcountrycode varchar(2);
2215 searchhousenumber TEXT;
2216 searchhousename HSTORE;
2217 searchrankaddress INTEGER;
2218 searchpostcode TEXT;
2225 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2226 WHERE place_id = in_place_id
2227 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2229 IF for_place_id IS NULL THEN
2230 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2231 WHERE place_id = in_place_id
2232 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2235 IF for_place_id IS NULL THEN
2236 select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex
2237 WHERE place_id = in_place_id and rank_address = 30
2238 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2241 IF for_place_id IS NULL THEN
2242 for_place_id := in_place_id;
2243 select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2244 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2247 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2250 hadcountry := false;
2252 select placex.place_id, osm_type, osm_id,
2253 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2254 class, type, admin_level, true as fromarea, true as isaddress,
2255 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2256 0 as distance, country_code
2258 where place_id = for_place_id
2260 --RAISE WARNING '%',location;
2261 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2262 searchcountrycode := location.country_code;
2264 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2265 location.isaddress := FALSE;
2267 IF location.rank_address = 4 AND location.isaddress THEN
2270 IF location.rank_address < 4 AND NOT hadcountry THEN
2271 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2272 IF countryname IS NOT NULL THEN
2273 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2274 RETURN NEXT countrylocation;
2277 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2278 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2279 location.distance)::addressline;
2280 RETURN NEXT countrylocation;
2281 found := location.rank_address;
2285 select placex.place_id, osm_type, osm_id,
2286 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2287 class, type, admin_level, fromarea, isaddress,
2288 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,
2289 distance,country_code
2290 from place_addressline join placex on (address_place_id = placex.place_id)
2291 where place_addressline.place_id = for_place_id
2292 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2293 and address_place_id != for_place_id
2294 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2295 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2297 --RAISE WARNING '%',location;
2298 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2299 searchcountrycode := location.country_code;
2301 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2302 location.isaddress := FALSE;
2304 IF location.rank_address = 4 AND location.isaddress THEN
2307 IF location.rank_address < 4 AND NOT hadcountry THEN
2308 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2309 IF countryname IS NOT NULL THEN
2310 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2311 RETURN NEXT countrylocation;
2314 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2315 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2316 location.distance)::addressline;
2317 RETURN NEXT countrylocation;
2318 found := location.rank_address;
2322 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2323 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2324 IF countryname IS NOT NULL THEN
2325 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2326 RETURN NEXT location;
2330 IF searchcountrycode IS NOT NULL THEN
2331 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2332 RETURN NEXT location;
2335 IF searchhousename IS NOT NULL THEN
2336 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2337 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2338 RETURN NEXT location;
2341 IF searchhousenumber IS NOT NULL THEN
2342 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2343 RETURN NEXT location;
2346 IF searchpostcode IS NOT NULL THEN
2347 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2348 RETURN NEXT location;
2356 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2359 result place_boundingbox;
2360 numfeatures integer;
2362 select * from place_boundingbox into result where place_id = search_place_id;
2363 IF result.place_id IS NULL THEN
2364 -- remove isaddress = true because if there is a matching polygon it always wins
2365 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2366 insert into place_boundingbox select place_id,
2367 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2368 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2369 numfeatures, ST_Area(geometry),
2370 geometry as area from location_area where place_id = search_place_id;
2371 select * from place_boundingbox into result where place_id = search_place_id;
2373 IF result.place_id IS NULL THEN
2375 insert into place_boundingbox select address_place_id,
2376 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2377 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2378 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2379 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2380 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)
2381 where address_place_id = search_place_id
2382 -- and (isaddress = true OR place_id = search_place_id)
2383 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2384 group by address_place_id limit 1;
2385 select * from place_boundingbox into result where place_id = search_place_id;
2392 -- don't do the operation if it would be slow
2393 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2396 result place_boundingbox;
2397 numfeatures integer;
2400 select * from place_boundingbox into result where place_id = search_place_id;
2401 IF result IS NULL AND rank > 14 THEN
2402 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2403 insert into place_boundingbox select place_id,
2404 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2405 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2406 numfeatures, ST_Area(geometry),
2407 geometry as area from location_area where place_id = search_place_id;
2408 select * from place_boundingbox into result where place_id = search_place_id;
2410 IF result IS NULL THEN
2411 select rank_search from placex where place_id = search_place_id into rank;
2414 insert into place_boundingbox select address_place_id,
2415 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2416 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2417 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2418 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2419 from place_addressline join placex using (place_id)
2420 where address_place_id = search_place_id
2421 and (isaddress = true OR place_id = search_place_id)
2422 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2423 group by address_place_id limit 1;
2424 select * from place_boundingbox into result where place_id = search_place_id;
2432 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2435 result place_boundingbox;
2436 numfeatures integer;
2440 housenumber = place.housenumber,
2441 street = place.street,
2443 postcode = place.postcode,
2444 country_code = place.country_code,
2445 parent_place_id = null
2447 where placex.place_id = search_place_id
2448 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2449 and place.class = placex.class and place.type = placex.type;
2450 update placex set indexed_status = 2 where place_id = search_place_id;
2451 update placex set indexed_status = 0 where place_id = search_place_id;
2457 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2463 ELSEIF rank < 4 THEN
2465 ELSEIF rank < 8 THEN
2467 ELSEIF rank < 12 THEN
2469 ELSEIF rank < 16 THEN
2471 ELSEIF rank = 16 THEN
2473 ELSEIF rank = 17 THEN
2474 RETURN 'Town / Island';
2475 ELSEIF rank = 18 THEN
2476 RETURN 'Village / Hamlet';
2477 ELSEIF rank = 20 THEN
2479 ELSEIF rank = 21 THEN
2480 RETURN 'Postcode Area';
2481 ELSEIF rank = 22 THEN
2482 RETURN 'Croft / Farm / Locality / Islet';
2483 ELSEIF rank = 23 THEN
2484 RETURN 'Postcode Area';
2485 ELSEIF rank = 25 THEN
2486 RETURN 'Postcode Point';
2487 ELSEIF rank = 26 THEN
2488 RETURN 'Street / Major Landmark';
2489 ELSEIF rank = 27 THEN
2490 RETURN 'Minory Street / Path';
2491 ELSEIF rank = 28 THEN
2492 RETURN 'House / Building';
2494 RETURN 'Other: '||rank;
2501 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2507 ELSEIF rank < 2 THEN
2509 ELSEIF rank < 4 THEN
2511 ELSEIF rank = 5 THEN
2513 ELSEIF rank < 8 THEN
2515 ELSEIF rank < 12 THEN
2517 ELSEIF rank < 16 THEN
2519 ELSEIF rank = 16 THEN
2521 ELSEIF rank = 17 THEN
2522 RETURN 'Town / Village / Hamlet';
2523 ELSEIF rank = 20 THEN
2525 ELSEIF rank = 21 THEN
2526 RETURN 'Postcode Area';
2527 ELSEIF rank = 22 THEN
2528 RETURN 'Croft / Farm / Locality / Islet';
2529 ELSEIF rank = 23 THEN
2530 RETURN 'Postcode Area';
2531 ELSEIF rank = 25 THEN
2532 RETURN 'Postcode Point';
2533 ELSEIF rank = 26 THEN
2534 RETURN 'Street / Major Landmark';
2535 ELSEIF rank = 27 THEN
2536 RETURN 'Minory Street / Path';
2537 ELSEIF rank = 28 THEN
2538 RETURN 'House / Building';
2540 RETURN 'Other: '||rank;
2547 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2554 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2555 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2562 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2570 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2572 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2573 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2575 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2583 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2584 in_endnumber INTEGER, interpolationtype TEXT,
2585 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2589 startnumber INTEGER;
2594 numberrange INTEGER;
2595 rangestartnumber INTEGER;
2596 place_centroid GEOMETRY;
2597 out_partition INTEGER;
2598 out_parent_place_id BIGINT;
2600 address_street_word_id INTEGER;
2604 IF in_endnumber > in_startnumber THEN
2605 startnumber = in_startnumber;
2606 endnumber = in_endnumber;
2608 startnumber = in_endnumber;
2609 endnumber = in_startnumber;
2612 numberrange := endnumber - startnumber;
2613 rangestartnumber := startnumber;
2615 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2616 startnumber := startnumber + 1;
2619 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2621 ELSE -- everything else assumed to be 'all'
2626 -- Filter out really broken tiger data
2627 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2628 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2629 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2630 ST_length(linegeo)/(numberrange::float/stepsize::float);
2634 place_centroid := ST_Centroid(linegeo);
2635 out_partition := get_partition(place_centroid, 'us');
2636 out_parent_place_id := null;
2638 address_street_word_id := get_name_id(make_standard_name(in_street));
2639 IF address_street_word_id IS NOT NULL THEN
2640 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2641 out_parent_place_id := location.place_id;
2645 IF out_parent_place_id IS NULL THEN
2646 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP
2647 out_parent_place_id := location.place_id;
2651 IF out_parent_place_id IS NULL THEN
2652 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2653 out_parent_place_id := location.place_id;
2658 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2659 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2660 values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode,
2661 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2662 newpoints := newpoints + 1;
2670 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2671 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2676 place_centroid GEOMETRY;
2677 out_partition INTEGER;
2678 out_parent_place_id BIGINT;
2680 address_street_word_id INTEGER;
2685 place_centroid := ST_Centroid(pointgeo);
2686 out_partition := get_partition(place_centroid, in_countrycode);
2687 out_parent_place_id := null;
2689 address_street_word_id := get_name_id(make_standard_name(in_street));
2690 IF address_street_word_id IS NOT NULL THEN
2691 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2692 out_parent_place_id := location.place_id;
2696 IF out_parent_place_id IS NULL THEN
2697 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2698 out_parent_place_id := location.place_id;
2702 out_postcode := in_postcode;
2703 IF out_postcode IS NULL THEN
2704 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2706 IF out_postcode IS NULL THEN
2707 out_postcode := getNearestPostcode(out_partition, place_centroid);
2711 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2712 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2713 newpoints := newpoints + 1;
2720 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2727 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2728 IF members[i+1] = member THEN
2729 result := result || members[i];
2738 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2744 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2745 IF members[i+1] = ANY(memberLabels) THEN
2746 RETURN NEXT members[i];
2755 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2756 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2758 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2759 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
2760 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2761 ), '') AS bytea), 'UTF8');
2763 LANGUAGE SQL IMMUTABLE STRICT;
2765 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2769 RETURN decode_url_part(p);
2771 WHEN others THEN return null;
2774 LANGUAGE plpgsql IMMUTABLE;
2776 DROP TYPE wikipedia_article_match CASCADE;
2777 create type wikipedia_article_match as (
2783 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE) RETURNS wikipedia_article_match
2789 wiki_article_title TEXT;
2790 wiki_article_language TEXT;
2791 result wikipedia_article_match;
2793 langs := ARRAY['','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'];
2795 WHILE langs[i] IS NOT NULL LOOP
2796 wiki_article := extratags->(case when langs[i] = '' THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2797 IF wiki_article is not null THEN
2798 wiki_article := replace(regexp_replace(wiki_article,E'(.*?)([a-z]+).wikipedia.org/wiki/',E'\\2:'),' ','_');
2799 wiki_article_title := split_part(wiki_article, ':', 2);
2800 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2801 wiki_article_title := wiki_article;
2802 wiki_article_language := CASE WHEN langs[i] = '' THEN 'en' ELSE langs[i] END;
2804 wiki_article_language := lower(split_part(wiki_article, ':', 1));
2807 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2808 from wikipedia_article
2809 where language = wiki_article_language and
2810 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2812 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2813 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2814 where wikipedia_redirect.language = wiki_article_language and
2815 (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'\\',''))
2816 order by importance desc limit 1 INTO result;
2818 IF result.language is not null THEN