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_PointOnSurface(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 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
938 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
939 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
941 -- copy 'name' to or from the default language (if there is a default language)
942 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
943 default_language := get_country_language_code(NEW.country_code);
944 IF default_language IS NOT NULL THEN
945 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
946 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
947 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
948 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
953 IF NEW.admin_level > 15 THEN
954 NEW.admin_level := 15;
957 IF NEW.housenumber IS NOT NULL THEN
958 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
961 IF NEW.osm_type = 'X' THEN
962 -- E'X'ternal records should already be in the right format so do nothing
964 NEW.rank_search := 30;
965 NEW.rank_address := NEW.rank_search;
967 -- By doing in postgres we have the country available to us - currently only used for postcode
968 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
970 IF NEW.postcode IS NULL THEN
971 -- most likely just a part of a multipolygon postcode boundary, throw it away
975 NEW.name := 'ref'=>NEW.postcode;
977 IF NEW.country_code = 'gb' THEN
979 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
980 NEW.rank_search := 25;
981 NEW.rank_address := 5;
982 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
983 NEW.rank_search := 23;
984 NEW.rank_address := 5;
985 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
986 NEW.rank_search := 21;
987 NEW.rank_address := 5;
990 ELSEIF NEW.country_code = 'de' THEN
992 IF NEW.postcode ~ '^([0-9]{5})$' THEN
993 NEW.rank_search := 21;
994 NEW.rank_address := 11;
998 -- Guess at the postcode format and coverage (!)
999 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1000 NEW.rank_search := 21;
1001 NEW.rank_address := 11;
1003 -- Does it look splitable into and area and local code?
1004 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1006 IF postcode IS NOT NULL THEN
1007 NEW.rank_search := 25;
1008 NEW.rank_address := 11;
1009 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1010 NEW.rank_search := 21;
1011 NEW.rank_address := 11;
1016 ELSEIF NEW.class = 'place' THEN
1017 IF NEW.type in ('continent') THEN
1018 NEW.rank_search := 2;
1019 NEW.rank_address := NEW.rank_search;
1020 NEW.country_code := NULL;
1021 ELSEIF NEW.type in ('sea') THEN
1022 NEW.rank_search := 2;
1023 NEW.rank_address := 0;
1024 NEW.country_code := NULL;
1025 ELSEIF NEW.type in ('country') THEN
1026 NEW.rank_search := 4;
1027 NEW.rank_address := NEW.rank_search;
1028 ELSEIF NEW.type in ('state') THEN
1029 NEW.rank_search := 8;
1030 NEW.rank_address := NEW.rank_search;
1031 ELSEIF NEW.type in ('region') THEN
1032 NEW.rank_search := 18; -- dropped from previous value of 10
1033 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1034 ELSEIF NEW.type in ('county') THEN
1035 NEW.rank_search := 12;
1036 NEW.rank_address := NEW.rank_search;
1037 ELSEIF NEW.type in ('city') THEN
1038 NEW.rank_search := 16;
1039 NEW.rank_address := NEW.rank_search;
1040 ELSEIF NEW.type in ('island') THEN
1041 NEW.rank_search := 17;
1042 NEW.rank_address := 0;
1043 ELSEIF NEW.type in ('town') THEN
1044 NEW.rank_search := 18;
1045 NEW.rank_address := 16;
1046 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1047 NEW.rank_search := 19;
1048 NEW.rank_address := 16;
1049 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1050 NEW.rank_search := 18;
1051 NEW.rank_address := 17;
1052 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1053 NEW.rank_search := 17;
1054 NEW.rank_address := 18;
1055 ELSEIF NEW.type in ('moor') THEN
1056 NEW.rank_search := 17;
1057 NEW.rank_address := 0;
1058 ELSEIF NEW.type in ('national_park') THEN
1059 NEW.rank_search := 18;
1060 NEW.rank_address := 18;
1061 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1062 NEW.rank_search := 20;
1063 NEW.rank_address := NEW.rank_search;
1064 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1065 NEW.rank_search := 20;
1066 NEW.rank_address := 0;
1067 -- Irish townlands, tagged as place=locality and locality=townland
1068 IF (NEW.extratags -> 'locality') = 'townland' THEN
1069 NEW.rank_address := 20;
1071 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1072 NEW.rank_search := 22;
1073 NEW.rank_address := 22;
1074 ELSEIF NEW.type in ('airport','street') THEN
1075 NEW.rank_search := 26;
1076 NEW.rank_address := NEW.rank_search;
1077 ELSEIF NEW.type in ('house','building') THEN
1078 NEW.rank_search := 30;
1079 NEW.rank_address := NEW.rank_search;
1080 ELSEIF NEW.type in ('houses') THEN
1081 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1082 -- insert new point into place for each derived building
1083 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1084 NEW.rank_search := 28;
1085 NEW.rank_address := 0;
1088 ELSEIF NEW.class = 'boundary' THEN
1089 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1090 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1093 NEW.rank_search := NEW.admin_level * 2;
1094 NEW.rank_address := NEW.rank_search;
1095 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1096 NEW.rank_search := 22;
1097 NEW.rank_address := NEW.rank_search;
1098 -- any feature more than 5 square miles is probably worth indexing
1099 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1100 NEW.rank_search := 22;
1101 NEW.rank_address := NEW.rank_search;
1102 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1103 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1104 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1106 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1108 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1110 ELSEIF NEW.class = 'waterway' THEN
1111 NEW.rank_address := 17;
1112 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
1113 NEW.rank_search := 27;
1114 NEW.rank_address := NEW.rank_search;
1115 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1116 NEW.rank_search := 26;
1117 NEW.rank_address := NEW.rank_search;
1118 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1119 NEW.rank_search := 4;
1120 NEW.rank_address := NEW.rank_search;
1121 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1123 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1124 NEW.rank_search := 18;
1125 NEW.rank_address := 0;
1130 IF NEW.rank_search > 30 THEN
1131 NEW.rank_search := 30;
1134 IF NEW.rank_address > 30 THEN
1135 NEW.rank_address := 30;
1138 IF (NEW.extratags -> 'capital') = 'yes' THEN
1139 NEW.rank_search := NEW.rank_search - 1;
1142 -- a country code make no sense below rank 4 (country)
1143 IF NEW.rank_address < 4 THEN
1144 NEW.country_code := NULL;
1147 -- Block import below rank 22
1148 -- IF NEW.rank_search > 22 THEN
1152 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1154 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1155 -- Performance: We just can't handle re-indexing for country level changes
1156 IF st_area(NEW.geometry) < 1 THEN
1157 -- mark items within the geometry for re-indexing
1158 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1160 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1161 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1162 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);
1163 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1164 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);
1167 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1169 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1170 IF NEW.type='postcode' THEN
1172 ELSEIF NEW.rank_search < 16 THEN
1174 ELSEIF NEW.rank_search < 18 THEN
1176 ELSEIF NEW.rank_search < 20 THEN
1178 ELSEIF NEW.rank_search = 21 THEN
1180 ELSEIF NEW.rank_search < 24 THEN
1182 ELSEIF NEW.rank_search < 26 THEN
1183 diameter := 0.002; -- 100 to 200 meters
1184 ELSEIF NEW.rank_search < 28 THEN
1185 diameter := 0.001; -- 50 to 100 meters
1187 IF diameter > 0 THEN
1188 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1189 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);
1194 -- add to tables for special search
1195 -- Note: won't work on initial import because the classtype tables
1196 -- do not yet exist. It won't hurt either.
1197 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1198 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1200 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1201 USING NEW.place_id, ST_Centroid(NEW.geometry);
1205 -- IF NEW.rank_search < 26 THEN
1206 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1215 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1220 place_centroid GEOMETRY;
1222 search_maxdistance FLOAT[];
1223 search_mindistance FLOAT[];
1224 address_havelevel BOOLEAN[];
1225 -- search_scores wordscore[];
1226 -- search_scores_pos INTEGER;
1233 relation_members TEXT[];
1235 linkedplacex RECORD;
1236 search_diameter FLOAT;
1237 search_prevdiameter FLOAT;
1238 search_maxrank INTEGER;
1239 address_maxrank INTEGER;
1240 address_street_word_id INTEGER;
1241 parent_place_id_rank BIGINT;
1246 location_rank_search INTEGER;
1247 location_distance FLOAT;
1251 default_language TEXT;
1252 name_vector INTEGER[];
1253 nameaddress_vector INTEGER[];
1255 linked_node_id BIGINT;
1260 --RAISE WARNING '%',NEW.place_id;
1261 --RAISE WARNING '%', NEW;
1263 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1264 -- Silently do nothing
1269 IF OLD.indexed_status = 100 THEN
1270 delete from placex where place_id = OLD.place_id;
1274 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1276 NEW.indexed_date = now();
1278 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1279 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1283 IF OLD.indexed_status > 1 THEN
1284 result := deleteSearchName(NEW.partition, NEW.place_id);
1285 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1286 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1287 result := deleteRoad(NEW.partition, NEW.place_id);
1288 result := deleteLocationArea(NEW.partition, NEW.place_id);
1289 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1292 -- reclaculate country and partition (should probably have a country_code and calculated_country_code as seperate fields)
1293 IF NEW.rank_search >= 4 THEN
1294 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;
1295 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1297 NEW.country_code := NULL;
1299 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
1300 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1302 -- Adding ourselves to the list simplifies address calculations later
1303 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1305 -- What level are we searching from
1306 search_maxrank := NEW.rank_search;
1308 -- Speed up searches - just use the centroid of the feature
1309 -- cheaper but less acurate
1310 place_centroid := ST_Centroid(NEW.geometry);
1311 NEW.centroid := null;
1313 -- Thought this wasn't needed but when we add new languages to the country_name table
1314 -- we need to update the existing names
1315 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1316 default_language := get_country_language_code(NEW.country_code);
1317 IF default_language IS NOT NULL THEN
1318 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1319 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1320 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1321 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1326 -- Initialise the name vector using our name
1327 name_vector := make_keywords(NEW.name);
1328 nameaddress_vector := '{}'::int[];
1330 -- some tag combinations add a special id for search
1331 tagpairid := get_tagpair(NEW.class,NEW.type);
1332 IF tagpairid IS NOT NULL THEN
1333 name_vector := name_vector + tagpairid;
1337 address_havelevel[i] := false;
1340 NEW.importance := null;
1341 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1342 IF NEW.importance IS NULL THEN
1343 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;
1346 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1348 -- For low level elements we inherit from our parent road
1349 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1351 --RAISE WARNING 'finding street for %', NEW;
1353 NEW.parent_place_id := null;
1355 -- to do that we have to find our parent road
1356 -- Copy data from linked items (points on ways, addr:street links, relations)
1357 -- Note that addr:street links can only be indexed once the street itself is indexed
1358 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1360 -- Is this node part of a relation?
1361 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1363 -- At the moment we only process one type of relation - associatedStreet
1364 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1365 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1366 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1367 --RAISE WARNING 'node in relation %',relation;
1368 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1369 and rank_search = 26 INTO NEW.parent_place_id;
1375 --RAISE WARNING 'x1';
1376 -- Is this node part of a way?
1377 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1378 --RAISE WARNING '%', way;
1379 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1381 --RAISE WARNING '%', location;
1382 -- Way IS a road then we are on it - that must be our road
1383 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1384 --RAISE WARNING 'node in way that is a street %',location;
1385 NEW.parent_place_id := location.place_id;
1388 -- Is the WAY part of a relation
1389 IF NEW.parent_place_id IS NULL THEN
1390 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1392 -- At the moment we only process one type of relation - associatedStreet
1393 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1394 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1395 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1396 --RAISE WARNING 'node in way that is in a relation %',relation;
1397 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1398 and rank_search = 26 INTO NEW.parent_place_id;
1405 -- If the way contains an explicit name of a street copy it
1406 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1407 --RAISE WARNING 'node in way that has a streetname %',location;
1408 NEW.street := location.street;
1411 -- If this way is a street interpolation line then it is probably as good as we are going to get
1412 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1413 -- Try and find a way that is close roughly parellel to this line
1414 FOR relation IN SELECT place_id FROM placex
1415 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1416 and st_geometrytype(location.geometry) in ('ST_LineString')
1417 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1418 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1419 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1421 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1422 NEW.parent_place_id := relation.place_id;
1431 --RAISE WARNING 'x2';
1433 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1434 -- Is this way part of a relation?
1435 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1437 -- At the moment we only process one type of relation - associatedStreet
1438 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1439 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1440 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1441 --RAISE WARNING 'way that is in a relation %',relation;
1442 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1443 and rank_search = 26 INTO NEW.parent_place_id;
1450 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1452 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1453 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1454 IF address_street_word_id IS NOT NULL THEN
1455 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1456 NEW.parent_place_id := location.place_id;
1461 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1462 -- Still nothing, just use the nearest road
1463 IF NEW.parent_place_id IS NULL THEN
1464 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1465 NEW.parent_place_id := location.place_id;
1470 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1472 -- If we didn't find any road fallback to standard method
1473 IF NEW.parent_place_id IS NOT NULL THEN
1475 -- Add the street to the address as zero distance to force to front of list
1476 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1477 address_havelevel[26] := true;
1479 -- Import address details from parent, reclculating distance in process
1480 -- 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
1481 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1482 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1484 -- Get the details of the parent road
1485 select * from search_name where place_id = NEW.parent_place_id INTO location;
1486 NEW.country_code := location.country_code;
1488 --RAISE WARNING '%', NEW.name;
1489 -- If there is no name it isn't searchable, don't bother to create a search record
1490 IF NEW.name is NULL THEN
1494 -- Merge address from parent
1495 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1497 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1498 -- Just be happy with inheriting from parent road only
1500 IF NEW.rank_search <= 25 THEN
1501 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1504 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1511 -- RAISE WARNING ' INDEXING: %',NEW;
1513 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1515 -- see if we have any special relation members
1516 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1518 -- RAISE WARNING 'get_osm_rel_members, label';
1519 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1521 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1522 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1524 -- If we don't already have one use this as the centre point of the geometry
1525 IF NEW.centroid IS NULL THEN
1526 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1529 -- merge in the label name, re-init word vector
1530 NEW.name := linkedPlacex.name || NEW.name;
1531 name_vector := make_keywords(NEW.name);
1533 -- merge in extra tags
1534 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1536 -- mark the linked place (excludes from search results)
1537 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1541 IF NEW.centroid IS NULL THEN
1543 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1545 select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1546 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 into linkedPlacex;
1548 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1549 -- But that can be fixed by explicitly setting the label in the data
1550 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1551 AND NEW.rank_search = linkedPlacex.rank_search THEN
1554 -- If we don't already have one use this as the centre point of the geometry
1555 IF NEW.centroid IS NULL THEN
1556 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1559 -- merge in the name, re-init word vector
1560 NEW.name := linkedPlacex.name || NEW.name;
1561 name_vector := make_keywords(NEW.name);
1563 -- merge in extra tags
1564 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1566 -- mark the linked place (excludes from search results)
1567 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1569 -- keep a note of the node id in case we need it for wikipedia in a bit
1570 linked_node_id := linkedPlacex.osm_id;
1577 -- not found one yet? how about doing a name search
1578 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1580 FOR linkedPlacex IN select placex.* from placex WHERE
1581 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1582 AND placex.rank_search = NEW.rank_search
1583 AND placex.place_id != NEW.place_id
1584 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1585 AND st_contains(NEW.geometry, placex.geometry)
1588 -- If we don't already have one use this as the centre point of the geometry
1589 IF NEW.centroid IS NULL THEN
1590 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1593 -- merge in the name, re-init word vector
1594 NEW.name := linkedPlacex.name || NEW.name;
1595 name_vector := make_keywords(NEW.name);
1597 -- merge in extra tags
1598 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1600 -- mark the linked place (excludes from search results)
1601 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1603 -- keep a note of the node id in case we need it for wikipedia in a bit
1604 linked_node_id := linkedPlacex.osm_id;
1608 IF NEW.centroid IS NOT NULL THEN
1609 place_centroid := NEW.centroid;
1612 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1613 IF NEW.importance is null THEN
1614 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1616 -- Still null? how about looking it up by the node id
1617 IF NEW.importance IS NULL THEN
1618 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;
1623 NEW.parent_place_id = 0;
1624 parent_place_id_rank = 0;
1626 -- convert isin to array of tokenids
1627 isin_tokens := '{}'::int[];
1628 IF NEW.isin IS NOT NULL THEN
1629 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1630 IF array_upper(isin, 1) IS NOT NULL THEN
1631 FOR i IN 1..array_upper(isin, 1) LOOP
1632 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1633 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1634 isin_tokens := isin_tokens || address_street_word_id;
1639 IF NEW.postcode IS NOT NULL THEN
1640 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1641 IF array_upper(isin, 1) IS NOT NULL THEN
1642 FOR i IN 1..array_upper(isin, 1) LOOP
1643 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1644 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1645 isin_tokens := isin_tokens || address_street_word_id;
1650 --RAISE WARNING 'ISIN: %', isin_tokens;
1652 -- Process area matches
1653 location_rank_search := 100;
1654 location_distance := 0;
1655 --RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1656 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1658 --RAISE WARNING ' AREA: %',location;
1660 IF location.rank_search < location_rank_search THEN
1661 location_rank_search := location.rank_search;
1662 location_distance := location.distance * 1.5;
1665 IF location.distance < location_distance OR NOT location.isguess THEN
1667 -- Add it to the list of search terms
1668 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1669 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1670 address_havelevel[location.rank_address] := true;
1672 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1674 IF location.rank_address > parent_place_id_rank THEN
1675 NEW.parent_place_id = location.place_id;
1676 parent_place_id_rank = location.rank_address;
1683 -- try using the isin value to find parent places
1684 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1685 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1686 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1688 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1690 --RAISE WARNING ' ISIN: %',location;
1692 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1693 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1694 address_havelevel[location.rank_address] := true;
1696 IF location.rank_address > parent_place_id_rank THEN
1697 NEW.parent_place_id = location.place_id;
1698 parent_place_id_rank = location.rank_address;
1706 -- for long ways we should add search terms for the entire length
1707 IF st_length(NEW.geometry) > 0.05 THEN
1709 location_rank_search := 100;
1710 location_distance := 0;
1712 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1714 IF location.rank_search < location_rank_search THEN
1715 location_rank_search := location.rank_search;
1716 location_distance := location.distance * 1.5;
1719 IF location.distance < location_distance THEN
1721 -- Add it to the list of search terms
1722 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1723 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1731 -- if we have a name add this to the name search table
1732 IF NEW.name IS NOT NULL THEN
1734 IF NEW.rank_search <= 25 THEN
1735 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1738 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1739 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1742 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1744 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1747 -- If we've not managed to pick up a better one - default centroid
1748 IF NEW.centroid IS NULL THEN
1749 NEW.centroid := place_centroid;
1759 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1766 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1767 update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1769 IF OLD.rank_address < 30 THEN
1771 -- mark everything linked to this place for re-indexing
1772 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1773 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1775 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1777 b := deleteRoad(OLD.partition, OLD.place_id);
1779 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1783 IF OLD.rank_address < 26 THEN
1784 b := deleteLocationArea(OLD.partition, OLD.place_id);
1787 IF OLD.name is not null THEN
1788 b := deleteSearchName(OLD.partition, OLD.place_id);
1791 DELETE FROM place_addressline where place_id = OLD.place_id;
1793 -- remove from tables for special search
1794 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1795 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1797 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1806 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1812 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1814 -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through
1815 IF st_area(OLD.geometry) > 2 THEN
1816 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1821 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;
1823 -- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1830 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1835 existingplacex RECORD;
1836 existinggeometry GEOMETRY;
1837 existingplace_id BIGINT;
1842 IF FALSE and NEW.osm_type = 'R' THEN
1843 RAISE WARNING '-----------------------------------------------------------------------------------';
1844 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1845 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;
1846 RAISE WARNING '%', existingplacex;
1849 -- Just block these - lots and pointless
1850 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1853 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1857 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
1858 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1859 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1860 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1864 -- Patch in additional country names
1865 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1866 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1869 -- Have we already done this place?
1870 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;
1872 -- Get the existing place_id
1873 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;
1875 -- Handle a place changing type by removing the old data
1876 -- My generated 'place' types are causing havok because they overlap with real keys
1877 -- TODO: move them to their own special purpose key/class to avoid collisions
1878 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1879 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');
1882 -- RAISE WARNING 'Existing: %',existing.place_id;
1885 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1886 AND st_area(existing.geometry) > 0.02
1887 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1888 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1890 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1891 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1895 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1896 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1898 -- 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
1899 IF existing.osm_type IS NULL
1900 OR existingplacex.osm_type IS NULL
1901 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1902 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1903 OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1904 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1907 -- IF existing.osm_type IS NULL THEN
1908 -- RAISE WARNING 'no existing place';
1910 -- IF existingplacex.osm_type IS NULL THEN
1911 -- RAISE WARNING 'no existing placex %', existingplacex;
1914 -- RAISE WARNING 'delete and replace';
1916 IF existing.osm_type IS NOT NULL THEN
1917 -- 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;
1918 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1921 -- RAISE WARNING 'delete and replace2';
1923 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1924 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1925 street, isin, postcode, country_code, extratags, geometry)
1926 values (NEW.osm_type
1941 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1946 -- Various ways to do the update
1948 -- Debug, what's changed?
1950 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1951 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1953 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1954 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1956 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1957 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1959 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1960 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1962 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1963 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1965 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1966 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1970 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1971 IF existing.geometry::text != NEW.geometry::text
1972 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1973 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1976 -- Get the version of the geometry actually used (in placex table)
1977 select geometry from placex where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type into existinggeometry;
1979 -- Performance limit
1980 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1982 -- re-index points that have moved in / out of the polygon, could be done as a single query but postgres gets the index usage wrong
1983 update placex set indexed_status = 2 where indexed_status = 0 and
1984 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1985 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1986 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1988 update placex set indexed_status = 2 where indexed_status = 0 and
1989 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1990 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1991 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1997 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1998 IF FALSE AND existingplacex.rank_search < 26
1999 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2000 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2001 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2002 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2003 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2004 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2007 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2009 IF st_area(NEW.geometry) < 0.5 THEN
2010 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2011 and placex.place_id = place_addressline.place_id and indexed_status = 0
2012 and (rank_search < 28 or name is not null);
2019 -- Anything else has changed - reindex the lot
2020 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2021 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2022 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2023 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2024 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2025 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2027 -- performance, can't take the load of re-indexing a whole country / huge area
2028 IF st_area(NEW.geometry) < 0.5 THEN
2029 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2030 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2037 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2038 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2039 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2040 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2041 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2042 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2043 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2044 OR existing.geometry::text != NEW.geometry::text
2049 housenumber = NEW.housenumber,
2050 street = NEW.street,
2052 postcode = NEW.postcode,
2053 country_code = NEW.country_code,
2054 extratags = NEW.extratags,
2055 geometry = NEW.geometry
2056 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2060 housenumber = NEW.housenumber,
2061 street = NEW.street,
2063 postcode = NEW.postcode,
2064 country_code = NEW.country_code,
2065 parent_place_id = null,
2066 extratags = NEW.extratags,
2068 geometry = NEW.geometry
2069 where place_id = existingplacex.place_id;
2071 -- now done as part of insert
2072 -- partition := get_partition(NEW.geometry, existingplacex.country_code);
2073 -- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
2077 -- Abort the add (we modified the existing place instead)
2081 $$ LANGUAGE plpgsql;
2083 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2090 IF name is null THEN
2094 search := languagepref;
2096 FOR j IN 1..array_upper(search, 1) LOOP
2097 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2098 return trim(name->search[j]);
2105 LANGUAGE plpgsql IMMUTABLE;
2107 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2110 searchnodes INTEGER[];
2115 searchnodes := '{}';
2116 FOR j IN 1..array_upper(way_ids, 1) LOOP
2118 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2120 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2121 searchnodes := searchnodes || location.nodes;
2126 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2129 LANGUAGE plpgsql IMMUTABLE;
2131 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2142 search := ARRAY['ref'];
2145 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2148 select rank_address,name,distance,length(name::text) as namelength
2149 from place_addressline join placex on (address_place_id = placex.place_id)
2150 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2151 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2153 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2154 FOR j IN 1..array_upper(search, 1) LOOP
2155 FOR k IN 1..array_upper(location.name, 1) LOOP
2156 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
2157 result[(100 - location.rank_address)] := trim(location.name[k].value);
2158 found := location.rank_address;
2165 RETURN array_to_string(result,', ');
2170 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2182 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2183 currresult := trim(get_name_by_language(location.name, languagepref));
2184 IF currresult != prevresult AND currresult IS NOT NULL THEN
2185 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2186 prevresult := currresult;
2190 RETURN array_to_string(result,', ');
2195 DROP TYPE addressline CASCADE;
2196 create type addressline as (
2203 admin_level INTEGER,
2206 rank_address INTEGER,
2210 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2213 for_place_id BIGINT;
2218 countrylocation RECORD;
2219 searchcountrycode varchar(2);
2220 searchhousenumber TEXT;
2221 searchhousename HSTORE;
2222 searchrankaddress INTEGER;
2223 searchpostcode TEXT;
2230 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2231 WHERE place_id = in_place_id
2232 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2234 IF for_place_id IS NULL THEN
2235 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2236 WHERE place_id = in_place_id
2237 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2240 IF for_place_id IS NULL THEN
2241 select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex
2242 WHERE place_id = in_place_id and rank_address = 30
2243 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2246 IF for_place_id IS NULL THEN
2247 for_place_id := in_place_id;
2248 select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2249 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2252 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2255 hadcountry := false;
2257 select placex.place_id, osm_type, osm_id,
2258 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2259 class, type, admin_level, true as fromarea, true as isaddress,
2260 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2261 0 as distance, country_code
2263 where place_id = for_place_id
2265 --RAISE WARNING '%',location;
2266 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2267 searchcountrycode := location.country_code;
2269 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2270 location.isaddress := FALSE;
2272 IF location.rank_address = 4 AND location.isaddress THEN
2275 IF location.rank_address < 4 AND NOT hadcountry THEN
2276 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2277 IF countryname IS NOT NULL THEN
2278 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2279 RETURN NEXT countrylocation;
2282 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2283 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2284 location.distance)::addressline;
2285 RETURN NEXT countrylocation;
2286 found := location.rank_address;
2290 select placex.place_id, osm_type, osm_id,
2291 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2292 class, type, admin_level, fromarea, isaddress,
2293 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,
2294 distance,country_code
2295 from place_addressline join placex on (address_place_id = placex.place_id)
2296 where place_addressline.place_id = for_place_id
2297 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2298 and address_place_id != for_place_id
2299 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2300 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2302 --RAISE WARNING '%',location;
2303 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2304 searchcountrycode := location.country_code;
2306 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2307 location.isaddress := FALSE;
2309 IF location.rank_address = 4 AND location.isaddress THEN
2312 IF location.rank_address < 4 AND NOT hadcountry THEN
2313 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2314 IF countryname IS NOT NULL THEN
2315 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2316 RETURN NEXT countrylocation;
2319 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2320 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2321 location.distance)::addressline;
2322 RETURN NEXT countrylocation;
2323 found := location.rank_address;
2327 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2328 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2329 IF countryname IS NOT NULL THEN
2330 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2331 RETURN NEXT location;
2335 IF searchcountrycode IS NOT NULL THEN
2336 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2337 RETURN NEXT location;
2340 IF searchhousename IS NOT NULL THEN
2341 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2342 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2343 RETURN NEXT location;
2346 IF searchhousenumber IS NOT NULL THEN
2347 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2348 RETURN NEXT location;
2351 IF searchpostcode IS NOT NULL THEN
2352 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2353 RETURN NEXT location;
2361 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2364 result place_boundingbox;
2365 numfeatures integer;
2367 select * from place_boundingbox into result where place_id = search_place_id;
2368 IF result.place_id IS NULL THEN
2369 -- remove isaddress = true because if there is a matching polygon it always wins
2370 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2371 insert into place_boundingbox select place_id,
2372 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2373 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2374 numfeatures, ST_Area(geometry),
2375 geometry as area from location_area where place_id = search_place_id;
2376 select * from place_boundingbox into result where place_id = search_place_id;
2378 IF result.place_id IS NULL THEN
2380 insert into place_boundingbox select address_place_id,
2381 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2382 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2383 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2384 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2385 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)
2386 where address_place_id = search_place_id
2387 -- and (isaddress = true OR place_id = search_place_id)
2388 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2389 group by address_place_id limit 1;
2390 select * from place_boundingbox into result where place_id = search_place_id;
2397 -- don't do the operation if it would be slow
2398 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2401 result place_boundingbox;
2402 numfeatures integer;
2405 select * from place_boundingbox into result where place_id = search_place_id;
2406 IF result IS NULL AND rank > 14 THEN
2407 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2408 insert into place_boundingbox select place_id,
2409 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2410 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2411 numfeatures, ST_Area(geometry),
2412 geometry as area from location_area where place_id = search_place_id;
2413 select * from place_boundingbox into result where place_id = search_place_id;
2415 IF result IS NULL THEN
2416 select rank_search from placex where place_id = search_place_id into rank;
2419 insert into place_boundingbox select address_place_id,
2420 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2421 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2422 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2423 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2424 from place_addressline join placex using (place_id)
2425 where address_place_id = search_place_id
2426 and (isaddress = true OR place_id = search_place_id)
2427 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2428 group by address_place_id limit 1;
2429 select * from place_boundingbox into result where place_id = search_place_id;
2437 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2440 result place_boundingbox;
2441 numfeatures integer;
2445 housenumber = place.housenumber,
2446 street = place.street,
2448 postcode = place.postcode,
2449 country_code = place.country_code,
2450 parent_place_id = null
2452 where placex.place_id = search_place_id
2453 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2454 and place.class = placex.class and place.type = placex.type;
2455 update placex set indexed_status = 2 where place_id = search_place_id;
2456 update placex set indexed_status = 0 where place_id = search_place_id;
2462 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2468 ELSEIF rank < 4 THEN
2470 ELSEIF rank < 8 THEN
2472 ELSEIF rank < 12 THEN
2474 ELSEIF rank < 16 THEN
2476 ELSEIF rank = 16 THEN
2478 ELSEIF rank = 17 THEN
2479 RETURN 'Town / Island';
2480 ELSEIF rank = 18 THEN
2481 RETURN 'Village / Hamlet';
2482 ELSEIF rank = 20 THEN
2484 ELSEIF rank = 21 THEN
2485 RETURN 'Postcode Area';
2486 ELSEIF rank = 22 THEN
2487 RETURN 'Croft / Farm / Locality / Islet';
2488 ELSEIF rank = 23 THEN
2489 RETURN 'Postcode Area';
2490 ELSEIF rank = 25 THEN
2491 RETURN 'Postcode Point';
2492 ELSEIF rank = 26 THEN
2493 RETURN 'Street / Major Landmark';
2494 ELSEIF rank = 27 THEN
2495 RETURN 'Minory Street / Path';
2496 ELSEIF rank = 28 THEN
2497 RETURN 'House / Building';
2499 RETURN 'Other: '||rank;
2506 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2512 ELSEIF rank < 2 THEN
2514 ELSEIF rank < 4 THEN
2516 ELSEIF rank = 5 THEN
2518 ELSEIF rank < 8 THEN
2520 ELSEIF rank < 12 THEN
2522 ELSEIF rank < 16 THEN
2524 ELSEIF rank = 16 THEN
2526 ELSEIF rank = 17 THEN
2527 RETURN 'Town / Village / Hamlet';
2528 ELSEIF rank = 20 THEN
2530 ELSEIF rank = 21 THEN
2531 RETURN 'Postcode Area';
2532 ELSEIF rank = 22 THEN
2533 RETURN 'Croft / Farm / Locality / Islet';
2534 ELSEIF rank = 23 THEN
2535 RETURN 'Postcode Area';
2536 ELSEIF rank = 25 THEN
2537 RETURN 'Postcode Point';
2538 ELSEIF rank = 26 THEN
2539 RETURN 'Street / Major Landmark';
2540 ELSEIF rank = 27 THEN
2541 RETURN 'Minory Street / Path';
2542 ELSEIF rank = 28 THEN
2543 RETURN 'House / Building';
2545 RETURN 'Other: '||rank;
2552 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2559 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2560 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2567 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2575 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2577 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2578 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2580 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2588 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2589 in_endnumber INTEGER, interpolationtype TEXT,
2590 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2594 startnumber INTEGER;
2599 numberrange INTEGER;
2600 rangestartnumber INTEGER;
2601 place_centroid GEOMETRY;
2602 out_partition INTEGER;
2603 out_parent_place_id BIGINT;
2605 address_street_word_id INTEGER;
2609 IF in_endnumber > in_startnumber THEN
2610 startnumber = in_startnumber;
2611 endnumber = in_endnumber;
2613 startnumber = in_endnumber;
2614 endnumber = in_startnumber;
2617 numberrange := endnumber - startnumber;
2618 rangestartnumber := startnumber;
2620 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2621 startnumber := startnumber + 1;
2624 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2626 ELSE -- everything else assumed to be 'all'
2631 -- Filter out really broken tiger data
2632 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2633 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2634 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2635 ST_length(linegeo)/(numberrange::float/stepsize::float);
2639 place_centroid := ST_Centroid(linegeo);
2640 out_partition := get_partition(place_centroid, 'us');
2641 out_parent_place_id := null;
2643 address_street_word_id := get_name_id(make_standard_name(in_street));
2644 IF address_street_word_id IS NOT NULL THEN
2645 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2646 out_parent_place_id := location.place_id;
2650 IF out_parent_place_id IS NULL THEN
2651 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP
2652 out_parent_place_id := location.place_id;
2656 IF out_parent_place_id IS NULL THEN
2657 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2658 out_parent_place_id := location.place_id;
2663 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2664 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2665 values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode,
2666 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2667 newpoints := newpoints + 1;
2675 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2676 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2681 place_centroid GEOMETRY;
2682 out_partition INTEGER;
2683 out_parent_place_id BIGINT;
2685 address_street_word_id INTEGER;
2690 place_centroid := ST_Centroid(pointgeo);
2691 out_partition := get_partition(place_centroid, in_countrycode);
2692 out_parent_place_id := null;
2694 address_street_word_id := get_name_id(make_standard_name(in_street));
2695 IF address_street_word_id IS NOT NULL THEN
2696 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2697 out_parent_place_id := location.place_id;
2701 IF out_parent_place_id IS NULL THEN
2702 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2703 out_parent_place_id := location.place_id;
2707 out_postcode := in_postcode;
2708 IF out_postcode IS NULL THEN
2709 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2711 IF out_postcode IS NULL THEN
2712 out_postcode := getNearestPostcode(out_partition, place_centroid);
2716 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2717 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2718 newpoints := newpoints + 1;
2725 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2732 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2733 IF members[i+1] = member THEN
2734 result := result || members[i];
2743 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2749 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2750 IF members[i+1] = ANY(memberLabels) THEN
2751 RETURN NEXT members[i];
2760 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2761 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2763 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2764 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
2765 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2766 ), '') AS bytea), 'UTF8');
2768 LANGUAGE SQL IMMUTABLE STRICT;
2770 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2774 RETURN decode_url_part(p);
2776 WHEN others THEN return null;
2779 LANGUAGE plpgsql IMMUTABLE;
2781 DROP TYPE wikipedia_article_match CASCADE;
2782 create type wikipedia_article_match as (
2788 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2794 wiki_article_title TEXT;
2795 wiki_article_language TEXT;
2796 result wikipedia_article_match;
2798 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'];
2800 WHILE langs[i] IS NOT NULL LOOP
2801 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2802 IF wiki_article is not null THEN
2803 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2804 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2805 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2806 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2807 wiki_article := replace(wiki_article,' ','_');
2808 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2809 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2810 wiki_article_title := trim(wiki_article);
2811 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;
2813 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2816 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2817 from wikipedia_article
2818 where language = wiki_article_language and
2819 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2821 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2822 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2823 where wikipedia_redirect.language = wiki_article_language and
2824 (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'\\',''))
2825 order by importance desc limit 1 INTO result;
2827 IF result.language is not null THEN