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);
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;
413 LANGUAGE plpgsql IMMUTABLE;
415 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
422 IF (wordscores is null OR words is null) THEN
427 FOR idxword in 1 .. array_upper(words, 1) LOOP
428 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
429 IF wordscores[idxscores].word = words[idxword] THEN
430 result := result + wordscores[idxscores].score;
438 LANGUAGE plpgsql IMMUTABLE;
440 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
443 place_centre GEOMETRY;
446 place_centre := ST_Centroid(place);
448 --RAISE WARNING 'start: %', ST_AsText(place_centre);
450 -- Try for a OSM polygon first
451 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
453 RETURN nearcountry.country_code;
456 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
458 -- Try for OSM fallback data
459 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
461 RETURN nearcountry.country_code;
464 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
466 -- Natural earth data (first fallback)
467 FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
469 RETURN nearcountry.country_code;
472 -- Natural earth data (first fallback)
473 FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1
475 RETURN nearcountry.country_code;
478 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
480 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
481 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
483 RETURN nearcountry.country_code;
486 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
488 -- Still not in a country - try nearest within ~12 miles of a country
489 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
490 order by st_distance(geometry, place) limit 1
492 RETURN nearcountry.country_code;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
505 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
507 RETURN nearcountry.country_code;
509 RETURN get_country_code(place);
512 LANGUAGE plpgsql IMMUTABLE;
514 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
519 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
521 RETURN lower(nearcountry.country_default_language_code);
526 LANGUAGE plpgsql IMMUTABLE;
528 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
531 place_centre GEOMETRY;
534 FOR nearcountry IN select partition from country_name where country_code = in_country_code
536 RETURN nearcountry.partition;
541 LANGUAGE plpgsql IMMUTABLE;
543 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
547 DELETE FROM location_area where place_id = OLD_place_id;
548 -- TODO:location_area
554 CREATE OR REPLACE FUNCTION add_location(
556 country_code varchar(2),
560 rank_address INTEGER,
581 IF rank_search > 25 THEN
582 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
585 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
587 x := deleteLocationArea(partition, place_id);
590 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
593 centroid := ST_Centroid(geometry);
595 xmin := floor(st_xmin(geometry));
596 xmax := ceil(st_xmax(geometry));
597 ymin := floor(st_ymin(geometry));
598 ymax := ceil(st_ymax(geometry));
600 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
601 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
603 -- RAISE WARNING 'Spliting geometry: % to %, % to %', xmin, xmax, ymin, ymax;
604 FOR lon IN xmin..(xmax-1) LOOP
605 FOR lat IN ymin..(ymax-1) LOOP
606 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
607 IF st_intersects(geometry, secbox) THEN
608 secgeo := st_intersection(geometry, secbox);
609 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
610 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
617 ELSEIF rank_search < 26 THEN
620 IF rank_address = 0 THEN
622 ELSEIF rank_search <= 14 THEN
624 ELSEIF rank_search <= 15 THEN
626 ELSEIF rank_search <= 16 THEN
628 ELSEIF rank_search <= 17 THEN
630 ELSEIF rank_search <= 21 THEN
632 ELSEIF rank_search = 25 THEN
636 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
638 secgeo := ST_Buffer(geometry, diameter);
639 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
644 secgeo := ST_Buffer(geometry, 0.0002);
645 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
648 secgeo := ST_Buffer(geometry, 0.001);
649 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
658 CREATE OR REPLACE FUNCTION update_location(
661 place_country_code varchar(2),
664 rank_address INTEGER,
672 b := deleteLocationArea(partition, place_id);
673 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
674 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
679 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
690 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
691 FOR childplace IN select * from search_name,place_addressline
692 where address_place_id = parent_place_id
693 and search_name.place_id = place_addressline.place_id
695 delete from search_name where place_id = childplace.place_id;
696 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
697 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
699 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
700 childplace.name_vector := childplace.name_vector || to_add;
702 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
703 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
704 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
712 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
715 newkeywords INTEGER[];
716 addedkeywords INTEGER[];
717 removedkeywords INTEGER[];
721 newkeywords := make_keywords(name);
722 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
723 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
724 where place_id = OLD_place_id into addedkeywords, removedkeywords;
726 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
728 IF #removedkeywords > 0 THEN
729 -- abort due to tokens removed
733 IF #addedkeywords > 0 THEN
734 -- short circuit - no changes
738 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
739 RETURN search_name_add_words(OLD_place_id, addedkeywords);
745 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
757 orginalstartnumber INTEGER;
758 originalnumberrange INTEGER;
761 search_place_id BIGINT;
764 havefirstpoint BOOLEAN;
768 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
770 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
771 select nodes from planet_osm_ways where id = wayid INTO waynodes;
772 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
773 IF array_upper(waynodes, 1) IS NOT NULL THEN
775 havefirstpoint := false;
777 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
779 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
780 IF search_place_id IS NULL THEN
781 -- null record of right type
782 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
783 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
785 select * from placex where place_id = search_place_id INTO nextnode;
788 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
790 IF havefirstpoint THEN
792 -- add point to the line string
793 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
794 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
796 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
798 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
800 IF startnumber != endnumber THEN
802 linestr := linestr || ')';
803 --RAISE WARNING 'linestr %',linestr;
804 linegeo := ST_GeomFromText(linestr,4326);
805 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
806 IF (startnumber > endnumber) THEN
807 housenum := endnumber;
808 endnumber := startnumber;
809 startnumber := housenum;
810 linegeo := ST_Reverse(linegeo);
812 orginalstartnumber := startnumber;
813 originalnumberrange := endnumber - startnumber;
815 -- Too much broken data worldwide for this test to be worth using
816 -- IF originalnumberrange > 500 THEN
817 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
820 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
821 startnumber := startnumber + 1;
824 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
825 startnumber := startnumber + 2;
827 ELSE -- everything else assumed to be 'all'
828 startnumber := startnumber + 1;
832 endnumber := endnumber - 1;
833 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
834 FOR housenum IN startnumber..endnumber BY stepsize LOOP
835 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
836 -- ideally postcodes should move up to the way
837 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
838 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
839 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
840 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));
841 newpoints := newpoints + 1;
842 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
845 havefirstpoint := false;
849 IF NOT havefirstpoint THEN
850 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
851 IF startnumber IS NOT NULL AND startnumber > 0 THEN
852 havefirstpoint := true;
853 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
854 prevnode := nextnode;
856 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
862 --RAISE WARNING 'interpolation points % ',newpoints;
869 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
875 country_code VARCHAR(2);
876 default_language VARCHAR(10);
880 -- RAISE WARNING '%',NEW.osm_id;
883 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
884 -- RAISE WARNING 'bad highway %',NEW.osm_id;
887 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
888 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
892 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
893 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
894 -- RAISE WARNING 'invalid geometry %',NEW.osm_id;
898 IF NEW.osm_type = 'R' THEN
899 -- invalid multipolygons can crash postgis, don't even bother to try!
902 NEW.geometry := ST_buffer(NEW.geometry,0);
903 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
904 -- RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
909 NEW.place_id := nextval('seq_place');
910 NEW.indexed_status := 1; --STATUS_NEW
912 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
913 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
914 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
916 -- copy 'name' to or from the default language (if there is a default language)
917 IF NEW.name is not null AND array_upper(%#NEW.name,1) > 1 THEN
918 default_language := get_country_language_code(NEW.country_code);
919 IF default_language IS NOT NULL THEN
920 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
921 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
922 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
923 NEW.name := NEW.name || ('name' => (NEW.name -> 'name:'||default_language));
928 IF NEW.admin_level > 15 THEN
929 NEW.admin_level := 15;
932 IF NEW.housenumber IS NOT NULL THEN
933 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
936 IF NEW.osm_type = 'X' THEN
937 -- E'X'ternal records should already be in the right format so do nothing
939 NEW.rank_search := 30;
940 NEW.rank_address := NEW.rank_search;
942 -- By doing in postgres we have the country available to us - currently only used for postcode
943 IF NEW.class = 'place' THEN
944 IF NEW.type in ('continent') THEN
945 NEW.rank_search := 2;
946 NEW.rank_address := NEW.rank_search;
947 ELSEIF NEW.type in ('sea') THEN
948 NEW.rank_search := 2;
949 NEW.rank_address := 0;
950 ELSEIF NEW.type in ('country') THEN
951 NEW.rank_search := 4;
952 NEW.rank_address := NEW.rank_search;
953 ELSEIF NEW.type in ('state') THEN
954 NEW.rank_search := 8;
955 NEW.rank_address := NEW.rank_search;
956 ELSEIF NEW.type in ('region') THEN
957 NEW.rank_search := 10;
958 NEW.rank_address := NEW.rank_search;
959 ELSEIF NEW.type in ('county') THEN
960 NEW.rank_search := 12;
961 NEW.rank_address := NEW.rank_search;
962 ELSEIF NEW.type in ('city') THEN
963 NEW.rank_search := 16;
964 NEW.rank_address := NEW.rank_search;
965 ELSEIF NEW.type in ('island') THEN
966 NEW.rank_search := 17;
967 NEW.rank_address := 0;
968 ELSEIF NEW.type in ('town') THEN
969 NEW.rank_search := 18;
970 NEW.rank_address := 16;
971 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
972 NEW.rank_search := 19;
973 NEW.rank_address := 16;
974 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
975 NEW.rank_search := 18;
976 NEW.rank_address := 17;
977 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
978 NEW.rank_search := 17;
979 NEW.rank_address := 18;
980 ELSEIF NEW.type in ('moor') THEN
981 NEW.rank_search := 17;
982 NEW.rank_address := 0;
983 ELSEIF NEW.type in ('national_park') THEN
984 NEW.rank_search := 18;
985 NEW.rank_address := 18;
986 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
987 NEW.rank_search := 20;
988 NEW.rank_address := NEW.rank_search;
989 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling') THEN
990 NEW.rank_search := 20;
991 NEW.rank_address := 0;
992 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
993 NEW.rank_search := 22;
994 NEW.rank_address := 22;
995 ELSEIF NEW.type in ('postcode') THEN
997 NEW.name := 'ref'=>NEW.postcode;
999 IF NEW.country_code = 'gb' THEN
1001 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1002 NEW.rank_search := 25;
1003 NEW.rank_address := 5;
1004 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1005 NEW.rank_search := 23;
1006 NEW.rank_address := 5;
1007 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1008 NEW.rank_search := 21;
1009 NEW.rank_address := 5;
1012 ELSEIF NEW.country_code = 'de' THEN
1014 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1015 NEW.rank_search := 21;
1016 NEW.rank_address := 11;
1020 -- Guess at the postcode format and coverage (!)
1021 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1022 NEW.rank_search := 21;
1023 NEW.rank_address := 11;
1025 -- Does it look splitable into and area and local code?
1026 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1028 IF postcode IS NOT NULL THEN
1029 NEW.rank_search := 25;
1030 NEW.rank_address := 11;
1031 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1032 NEW.rank_search := 21;
1033 NEW.rank_address := 11;
1038 ELSEIF NEW.type in ('airport','street') THEN
1039 NEW.rank_search := 26;
1040 NEW.rank_address := NEW.rank_search;
1041 ELSEIF NEW.type in ('house','building') THEN
1042 NEW.rank_search := 30;
1043 NEW.rank_address := NEW.rank_search;
1044 ELSEIF NEW.type in ('houses') THEN
1045 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1046 -- insert new point into place for each derived building
1047 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1048 NEW.rank_search := 28;
1049 NEW.rank_address := 0;
1052 ELSEIF NEW.class = 'boundary' THEN
1053 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1054 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1057 NEW.rank_search := NEW.admin_level * 2;
1058 NEW.rank_address := NEW.rank_search;
1059 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1060 NEW.rank_search := 22;
1061 NEW.rank_address := NEW.rank_search;
1062 -- any feature more than 5 square miles is probably worth indexing
1063 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1064 NEW.rank_search := 22;
1065 NEW.rank_address := NEW.rank_search;
1066 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1067 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1068 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1070 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1072 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1074 ELSEIF NEW.class = 'waterway' THEN
1075 NEW.rank_address := 17;
1076 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
1077 NEW.rank_search := 27;
1078 NEW.rank_address := NEW.rank_search;
1079 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1080 NEW.rank_search := 26;
1081 NEW.rank_address := NEW.rank_search;
1082 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1083 NEW.rank_search := 4;
1084 NEW.rank_address := NEW.rank_search;
1085 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1087 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1088 NEW.rank_search := 18;
1089 NEW.rank_address := 0;
1094 IF NEW.rank_search > 30 THEN
1095 NEW.rank_search := 30;
1098 IF NEW.rank_address > 30 THEN
1099 NEW.rank_address := 30;
1102 IF (NEW.extratags -> 'capital') = 'yes' THEN
1103 NEW.rank_search := NEW.rank_search -1;
1106 -- Block import below rank 22
1107 -- IF NEW.rank_search > 22 THEN
1111 RETURN NEW; -- The following is not needed until doing diff updates, and slows the main index process down
1113 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1114 -- Performance: We just can't handle re-indexing for country level changes
1115 IF st_area(NEW.geometry) < 1 THEN
1116 -- mark items within the geometry for re-indexing
1117 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1118 -- work around bug in postgis
1119 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1120 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1121 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1122 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1125 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1127 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1128 IF NEW.type='postcode' THEN
1130 ELSEIF NEW.rank_search < 16 THEN
1132 ELSEIF NEW.rank_search < 18 THEN
1134 ELSEIF NEW.rank_search < 20 THEN
1136 ELSEIF NEW.rank_search = 21 THEN
1138 ELSEIF NEW.rank_search < 24 THEN
1140 ELSEIF NEW.rank_search < 26 THEN
1141 diameter := 0.002; -- 100 to 200 meters
1142 ELSEIF NEW.rank_search < 28 THEN
1143 diameter := 0.001; -- 50 to 100 meters
1145 IF diameter > 0 THEN
1146 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1147 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1152 -- add to tables for special search
1153 -- Note: won't work on initial import because the classtype tables
1154 -- do not yet exist. It won't hurt either.
1155 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1156 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1158 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1159 USING NEW.place_id, ST_Centroid(NEW.geometry);
1163 -- IF NEW.rank_search < 26 THEN
1164 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1173 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1178 place_centroid GEOMETRY;
1180 search_maxdistance FLOAT[];
1181 search_mindistance FLOAT[];
1182 address_havelevel BOOLEAN[];
1183 -- search_scores wordscore[];
1184 -- search_scores_pos INTEGER;
1191 search_diameter FLOAT;
1192 search_prevdiameter FLOAT;
1193 search_maxrank INTEGER;
1194 address_maxrank INTEGER;
1195 address_street_word_id INTEGER;
1196 parent_place_id_rank BIGINT;
1201 location_rank_search INTEGER;
1202 location_distance FLOAT;
1206 name_vector INTEGER[];
1207 nameaddress_vector INTEGER[];
1212 --RAISE WARNING '%',NEW.place_id;
1213 --RAISE WARNING '%', NEW;
1215 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1216 -- Silently do nothing
1221 IF OLD.indexed_status = 100 THEN
1222 delete from placex where place_id = OLD.place_id;
1226 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1228 NEW.indexed_date = now();
1230 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1231 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1235 result := deleteSearchName(NEW.partition, NEW.place_id);
1236 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1237 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1238 result := deleteRoad(NEW.partition, NEW.place_id);
1239 result := deleteLocationArea(NEW.partition, NEW.place_id);
1241 -- reclaculate country and partition (should probably have a country_code and calculated_country_code as seperate fields)
1242 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;
1243 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1244 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
1245 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1247 -- Adding ourselves to the list simplifies address calculations later
1248 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1250 -- What level are we searching from
1251 search_maxrank := NEW.rank_search;
1253 -- Speed up searches - just use the centroid of the feature
1254 -- cheaper but less acurate
1255 place_centroid := ST_Centroid(NEW.geometry);
1257 -- Initialise the name vector using our name
1258 name_vector := make_keywords(NEW.name);
1259 nameaddress_vector := '{}'::int[];
1261 -- some tag combinations add a special id for search
1262 tagpairid := get_tagpair(NEW.class,NEW.type);
1263 IF tagpairid IS NOT NULL THEN
1264 name_vector := name_vector + tagpairid;
1268 address_havelevel[i] := false;
1271 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1273 -- For low level elements we inherit from our parent road
1274 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1276 --RAISE WARNING 'finding street for %', NEW;
1278 NEW.parent_place_id := null;
1280 -- to do that we have to find our parent road
1281 -- Copy data from linked items (points on ways, addr:street links, relations)
1282 -- Note that addr:street links can only be indexed once the street itself is indexed
1283 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1285 -- Is this node part of a relation?
1286 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1288 -- At the moment we only process one type of relation - associatedStreet
1289 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1290 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1291 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1292 --RAISE WARNING 'node in relation %',relation;
1293 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1294 and rank_search = 26 INTO NEW.parent_place_id;
1300 --RAISE WARNING 'x1';
1301 -- Is this node part of a way?
1302 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id::integer] LOOP
1303 --RAISE WARNING '%', way;
1304 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1306 --RAISE WARNING '%', location;
1307 -- Way IS a road then we are on it - that must be our road
1308 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1309 --RAISE WARNING 'node in way that is a street %',location;
1310 NEW.parent_place_id := location.place_id;
1313 -- Is the WAY part of a relation
1314 IF NEW.parent_place_id IS NULL THEN
1315 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1317 -- At the moment we only process one type of relation - associatedStreet
1318 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1319 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1320 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1321 --RAISE WARNING 'node in way that is in a relation %',relation;
1322 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1323 and rank_search = 26 INTO NEW.parent_place_id;
1330 -- If the way contains an explicit name of a street copy it
1331 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1332 --RAISE WARNING 'node in way that has a streetname %',location;
1333 NEW.street := location.street;
1336 -- If this way is a street interpolation line then it is probably as good as we are going to get
1337 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1338 -- Try and find a way that is close roughly parellel to this line
1339 FOR relation IN SELECT place_id FROM placex
1340 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1341 and st_geometrytype(location.geometry) in ('ST_LineString')
1342 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1343 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1344 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1346 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1347 NEW.parent_place_id := relation.place_id;
1356 --RAISE WARNING 'x2';
1358 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1359 -- Is this way part of a relation?
1360 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1362 -- At the moment we only process one type of relation - associatedStreet
1363 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1364 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1365 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1366 --RAISE WARNING 'way that is in a relation %',relation;
1367 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1368 and rank_search = 26 INTO NEW.parent_place_id;
1375 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1377 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1378 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1379 IF address_street_word_id IS NOT NULL THEN
1380 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1381 NEW.parent_place_id := location.place_id;
1386 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1387 -- Still nothing, just use the nearest road
1388 IF NEW.parent_place_id IS NULL THEN
1389 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1390 NEW.parent_place_id := location.place_id;
1395 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1397 -- If we didn't find any road fallback to standard method
1398 IF NEW.parent_place_id IS NOT NULL THEN
1400 -- Add the street to the address as zero distance to force to front of list
1401 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1402 address_havelevel[26] := true;
1404 -- Import address details from parent, reclculating distance in process
1405 -- 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
1406 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1407 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1409 -- Get the details of the parent road
1410 select * from search_name where place_id = NEW.parent_place_id INTO location;
1411 NEW.country_code := location.country_code;
1413 --RAISE WARNING '%', NEW.name;
1414 -- If there is no name it isn't searchable, don't bother to create a search record
1415 IF NEW.name is NULL THEN
1419 -- Merge address from parent
1420 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1422 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1423 -- Just be happy with inheriting from parent road only
1425 IF NEW.rank_search <= 25 THEN
1426 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1429 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1436 -- RAISE WARNING ' INDEXING: %',NEW;
1438 NEW.parent_place_id = 0;
1439 parent_place_id_rank = 0;
1441 -- convert isin to array of tokenids
1442 isin_tokens := '{}'::int[];
1443 IF NEW.isin IS NOT NULL THEN
1444 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1445 IF array_upper(isin, 1) IS NOT NULL THEN
1446 FOR i IN 1..array_upper(isin, 1) LOOP
1447 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1448 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1449 isin_tokens := isin_tokens || address_street_word_id;
1454 IF NEW.postcode IS NOT NULL THEN
1455 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1456 IF array_upper(isin, 1) IS NOT NULL THEN
1457 FOR i IN 1..array_upper(isin, 1) LOOP
1458 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1459 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1460 isin_tokens := isin_tokens || address_street_word_id;
1465 --RAISE WARNING 'ISIN: %', isin_tokens;
1467 -- Process area matches
1468 location_rank_search := 100;
1469 location_distance := 0;
1470 --RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1471 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1473 --RAISE WARNING ' AREA: %',location;
1475 IF location.rank_search < location_rank_search THEN
1476 location_rank_search := location.rank_search;
1477 location_distance := location.distance * 1.5;
1480 IF location.distance < location_distance OR NOT location.isguess THEN
1482 -- Add it to the list of search terms
1483 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1484 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1485 address_havelevel[location.rank_address] := true;
1487 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1489 IF location.rank_address > parent_place_id_rank THEN
1490 NEW.parent_place_id = location.place_id;
1491 parent_place_id_rank = location.rank_address;
1498 -- try using the isin value to find parent places
1499 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1500 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1501 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1503 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1505 --RAISE WARNING ' ISIN: %',location;
1507 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1508 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1509 address_havelevel[location.rank_address] := true;
1511 IF location.rank_address > parent_place_id_rank THEN
1512 NEW.parent_place_id = location.place_id;
1513 parent_place_id_rank = location.rank_address;
1521 -- for long ways we should add search terms for the entire length
1522 IF st_length(NEW.geometry) > 0.05 THEN
1524 location_rank_search := 100;
1525 location_distance := 0;
1527 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1529 IF location.rank_search < location_rank_search THEN
1530 location_rank_search := location.rank_search;
1531 location_distance := location.distance * 1.5;
1534 IF location.distance < location_distance THEN
1536 -- Add it to the list of search terms
1537 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1538 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1546 -- if we have a name add this to the name search table
1547 IF NEW.name IS NOT NULL THEN
1549 IF NEW.rank_search <= 25 THEN
1550 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1553 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1554 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1557 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1559 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1569 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1576 IF OLD.rank_address < 30 THEN
1578 -- mark everything linked to this place for re-indexing
1579 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1580 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1582 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1584 b := deleteRoad(OLD.partition, OLD.place_id);
1586 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1590 IF OLD.rank_address < 26 THEN
1591 b := deleteLocationArea(OLD.partition, OLD.place_id);
1594 IF OLD.name is not null THEN
1595 b := deleteSearchName(OLD.partition, OLD.place_id);
1598 DELETE FROM place_addressline where place_id = OLD.place_id;
1600 -- remove from tables for special search
1601 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1602 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1604 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1613 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1619 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1621 -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through
1622 IF st_area(OLD.geometry) > 2 THEN
1623 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1628 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;
1630 -- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1637 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1642 existingplacex RECORD;
1643 existinggeometry GEOMETRY;
1644 existingplace_id BIGINT;
1649 IF FALSE and NEW.osm_type = 'R' THEN
1650 RAISE WARNING '-----------------------------------------------------------------------------------';
1651 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1652 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;
1653 RAISE WARNING '%', existingplacex;
1656 -- Just block these - lots and pointless
1657 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1660 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1664 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
1665 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1666 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1667 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1671 -- Patch in additional country names
1672 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1673 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1676 -- Have we already done this place?
1677 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;
1679 -- Get the existing place_id
1680 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;
1682 -- Handle a place changing type by removing the old data
1683 -- My generated 'place' types are causing havok because they overlap with real keys
1684 -- TODO: move them to their own special purpose key/class to avoid collisions
1685 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1686 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');
1689 -- RAISE WARNING 'Existing: %',existing.place_id;
1692 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1693 AND st_area(existing.geometry) > 0.02
1694 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1695 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1697 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1698 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1702 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1703 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1705 -- 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
1706 IF existing.osm_type IS NULL
1707 OR existingplacex.osm_type IS NULL
1708 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1709 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1710 OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1711 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1714 -- IF existing.osm_type IS NULL THEN
1715 -- RAISE WARNING 'no existing place';
1717 -- IF existingplacex.osm_type IS NULL THEN
1718 -- RAISE WARNING 'no existing placex %', existingplacex;
1721 -- RAISE WARNING 'delete and replace';
1723 IF existing.osm_type IS NOT NULL THEN
1724 -- 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;
1725 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1728 -- RAISE WARNING 'delete and replace2';
1730 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1731 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1732 street, isin, postcode, country_code, extratags, geometry)
1733 values (NEW.osm_type
1748 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1753 -- Various ways to do the update
1755 -- Debug, what's changed?
1757 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1758 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1760 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1761 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1763 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1764 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1766 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1767 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1769 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1770 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1772 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1773 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1777 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1778 IF existing.geometry::text != NEW.geometry::text
1779 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1780 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1783 -- Get the version of the geometry actually used (in placex table)
1784 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;
1786 -- Performance limit
1787 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1789 -- 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
1790 update placex set indexed_status = 2 where indexed_status = 0 and
1791 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1792 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1793 AND rank_search > existingplacex.rank_search;
1795 update placex set indexed_status = 2 where indexed_status = 0 and
1796 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1797 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1798 AND rank_search > existingplacex.rank_search;
1804 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1805 IF FALSE AND existingplacex.rank_search < 26
1806 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1807 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1808 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1809 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1810 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1811 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1814 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1816 IF st_area(NEW.geometry) < 0.5 THEN
1817 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1818 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1825 -- Anything else has changed - reindex the lot
1826 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1827 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1828 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1829 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1830 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1831 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1833 -- performance, can't take the load of re-indexing a whole country / huge area
1834 IF st_area(NEW.geometry) < 0.5 THEN
1835 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1836 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
1843 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1844 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
1845 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1846 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1847 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1848 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1849 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1850 OR existing.geometry::text != NEW.geometry::text
1855 housenumber = NEW.housenumber,
1856 street = NEW.street,
1858 postcode = NEW.postcode,
1859 country_code = NEW.country_code,
1860 extratags = NEW.extratags,
1861 geometry = NEW.geometry
1862 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1866 housenumber = NEW.housenumber,
1867 street = NEW.street,
1869 postcode = NEW.postcode,
1870 country_code = NEW.country_code,
1871 parent_place_id = null,
1872 extratags = NEW.extratags,
1874 geometry = NEW.geometry
1875 where place_id = existingplacex.place_id;
1877 -- now done as part of insert
1878 -- partition := get_partition(NEW.geometry, existingplacex.country_code);
1879 -- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1883 -- Abort the add (we modified the existing place instead)
1887 $$ LANGUAGE plpgsql;
1889 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1896 IF name is null THEN
1900 search := languagepref;
1902 FOR j IN 1..array_upper(search, 1) LOOP
1903 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1904 return trim(name->search[j]);
1911 LANGUAGE plpgsql IMMUTABLE;
1913 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1916 searchnodes INTEGER[];
1921 searchnodes := '{}';
1922 FOR j IN 1..array_upper(way_ids, 1) LOOP
1924 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1926 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
1927 searchnodes := searchnodes || location.nodes;
1932 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1935 LANGUAGE plpgsql IMMUTABLE;
1937 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
1948 search := ARRAY['ref'];
1951 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1954 select rank_address,name,distance,length(name::text) as namelength
1955 from place_addressline join placex on (address_place_id = placex.place_id)
1956 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1957 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1959 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1960 FOR j IN 1..array_upper(search, 1) LOOP
1961 FOR k IN 1..array_upper(location.name, 1) LOOP
1962 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
1963 result[(100 - location.rank_address)] := trim(location.name[k].value);
1964 found := location.rank_address;
1971 RETURN array_to_string(result,', ');
1976 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
1988 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
1989 currresult := trim(get_name_by_language(location.name, languagepref));
1990 IF currresult != prevresult AND currresult IS NOT NULL THEN
1991 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
1992 prevresult := currresult;
1996 RETURN array_to_string(result,', ');
2001 DROP TYPE addressline CASCADE;
2002 create type addressline as (
2009 admin_level INTEGER,
2012 rank_address INTEGER,
2016 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2019 for_place_id BIGINT;
2024 countrylocation RECORD;
2025 searchcountrycode varchar(2);
2026 searchhousenumber TEXT;
2027 searchhousename HSTORE;
2028 searchrankaddress INTEGER;
2029 searchpostcode TEXT;
2036 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2037 WHERE place_id = in_place_id
2038 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2040 IF for_place_id IS NULL THEN
2041 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2042 WHERE place_id = in_place_id
2043 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2046 IF for_place_id IS NULL THEN
2047 select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex
2048 WHERE place_id = in_place_id and rank_address = 30
2049 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2052 IF for_place_id IS NULL THEN
2053 for_place_id := in_place_id;
2054 select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2055 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2058 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2061 hadcountry := false;
2063 select placex.place_id, osm_type, osm_id,
2064 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2065 class, type, admin_level, true as fromarea, true as isaddress,
2066 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2067 0 as distance, country_code
2069 where place_id = for_place_id
2071 --RAISE WARNING '%',location;
2072 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2073 searchcountrycode := location.country_code;
2075 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2076 location.isaddress := FALSE;
2078 IF location.rank_address = 4 AND location.isaddress THEN
2081 IF location.rank_address < 4 AND NOT hadcountry THEN
2082 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2083 IF countryname IS NOT NULL THEN
2084 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2085 RETURN NEXT countrylocation;
2088 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2089 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2090 location.distance)::addressline;
2091 RETURN NEXT countrylocation;
2092 found := location.rank_address;
2096 select placex.place_id, osm_type, osm_id,
2097 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2098 class, type, admin_level, fromarea, isaddress,
2099 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,
2100 distance,country_code
2101 from place_addressline join placex on (address_place_id = placex.place_id)
2102 where place_addressline.place_id = for_place_id
2103 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2104 and address_place_id != for_place_id
2105 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2106 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2108 --RAISE WARNING '%',location;
2109 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2110 searchcountrycode := location.country_code;
2112 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2113 location.isaddress := FALSE;
2115 IF location.rank_address = 4 AND location.isaddress THEN
2118 IF location.rank_address < 4 AND NOT hadcountry THEN
2119 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2120 IF countryname IS NOT NULL THEN
2121 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2122 RETURN NEXT countrylocation;
2125 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2126 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2127 location.distance)::addressline;
2128 RETURN NEXT countrylocation;
2129 found := location.rank_address;
2133 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2134 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2135 IF countryname IS NOT NULL THEN
2136 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2137 RETURN NEXT location;
2141 IF searchcountrycode IS NOT NULL THEN
2142 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2143 RETURN NEXT location;
2146 IF searchhousename IS NOT NULL THEN
2147 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2148 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2149 RETURN NEXT location;
2152 IF searchhousenumber IS NOT NULL THEN
2153 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2154 RETURN NEXT location;
2157 IF searchpostcode IS NOT NULL THEN
2158 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2159 RETURN NEXT location;
2167 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2170 result place_boundingbox;
2171 numfeatures integer;
2173 select * from place_boundingbox into result where place_id = search_place_id;
2174 IF result.place_id IS NULL THEN
2175 -- remove isaddress = true because if there is a matching polygon it always wins
2176 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2177 insert into place_boundingbox select place_id,
2178 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2179 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2180 numfeatures, ST_Area(geometry),
2181 geometry as area from location_area where place_id = search_place_id;
2182 select * from place_boundingbox into result where place_id = search_place_id;
2184 IF result.place_id IS NULL THEN
2186 insert into place_boundingbox select address_place_id,
2187 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2188 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2189 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2190 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2191 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)
2192 where address_place_id = search_place_id
2193 -- and (isaddress = true OR place_id = search_place_id)
2194 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2195 group by address_place_id limit 1;
2196 select * from place_boundingbox into result where place_id = search_place_id;
2203 -- don't do the operation if it would be slow
2204 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2207 result place_boundingbox;
2208 numfeatures integer;
2211 select * from place_boundingbox into result where place_id = search_place_id;
2212 IF result IS NULL AND rank > 14 THEN
2213 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2214 insert into place_boundingbox select place_id,
2215 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2216 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2217 numfeatures, ST_Area(geometry),
2218 geometry as area from location_area where place_id = search_place_id;
2219 select * from place_boundingbox into result where place_id = search_place_id;
2221 IF result IS NULL THEN
2222 select rank_search from placex where place_id = search_place_id into rank;
2225 insert into place_boundingbox select address_place_id,
2226 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2227 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2228 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2229 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2230 from place_addressline join placex using (place_id)
2231 where address_place_id = search_place_id
2232 and (isaddress = true OR place_id = search_place_id)
2233 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2234 group by address_place_id limit 1;
2235 select * from place_boundingbox into result where place_id = search_place_id;
2243 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2246 result place_boundingbox;
2247 numfeatures integer;
2251 housenumber = place.housenumber,
2252 street = place.street,
2254 postcode = place.postcode,
2255 country_code = place.country_code,
2256 parent_place_id = null
2258 where placex.place_id = search_place_id
2259 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2260 and place.class = placex.class and place.type = placex.type;
2261 update placex set indexed_status = 2 where place_id = search_place_id;
2262 update placex set indexed_status = 0 where place_id = search_place_id;
2268 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2274 ELSEIF rank < 4 THEN
2276 ELSEIF rank < 8 THEN
2278 ELSEIF rank < 12 THEN
2280 ELSEIF rank < 16 THEN
2282 ELSEIF rank = 16 THEN
2284 ELSEIF rank = 17 THEN
2285 RETURN 'Town / Island';
2286 ELSEIF rank = 18 THEN
2287 RETURN 'Village / Hamlet';
2288 ELSEIF rank = 20 THEN
2290 ELSEIF rank = 21 THEN
2291 RETURN 'Postcode Area';
2292 ELSEIF rank = 22 THEN
2293 RETURN 'Croft / Farm / Locality / Islet';
2294 ELSEIF rank = 23 THEN
2295 RETURN 'Postcode Area';
2296 ELSEIF rank = 25 THEN
2297 RETURN 'Postcode Point';
2298 ELSEIF rank = 26 THEN
2299 RETURN 'Street / Major Landmark';
2300 ELSEIF rank = 27 THEN
2301 RETURN 'Minory Street / Path';
2302 ELSEIF rank = 28 THEN
2303 RETURN 'House / Building';
2305 RETURN 'Other: '||rank;
2312 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2318 ELSEIF rank < 2 THEN
2320 ELSEIF rank < 4 THEN
2322 ELSEIF rank = 5 THEN
2324 ELSEIF rank < 8 THEN
2326 ELSEIF rank < 12 THEN
2328 ELSEIF rank < 16 THEN
2330 ELSEIF rank = 16 THEN
2332 ELSEIF rank = 17 THEN
2333 RETURN 'Town / Village / Hamlet';
2334 ELSEIF rank = 20 THEN
2336 ELSEIF rank = 21 THEN
2337 RETURN 'Postcode Area';
2338 ELSEIF rank = 22 THEN
2339 RETURN 'Croft / Farm / Locality / Islet';
2340 ELSEIF rank = 23 THEN
2341 RETURN 'Postcode Area';
2342 ELSEIF rank = 25 THEN
2343 RETURN 'Postcode Point';
2344 ELSEIF rank = 26 THEN
2345 RETURN 'Street / Major Landmark';
2346 ELSEIF rank = 27 THEN
2347 RETURN 'Minory Street / Path';
2348 ELSEIF rank = 28 THEN
2349 RETURN 'House / Building';
2351 RETURN 'Other: '||rank;
2358 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2365 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2366 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2373 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2381 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2383 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2384 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2386 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2394 CREATE AGGREGATE array_agg(INT[])
2401 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2402 in_endnumber INTEGER, interpolationtype TEXT,
2403 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2407 startnumber INTEGER;
2412 numberrange INTEGER;
2413 rangestartnumber INTEGER;
2414 place_centroid GEOMETRY;
2416 parent_place_id BIGINT;
2418 address_street_word_id INTEGER;
2422 IF in_endnumber > in_startnumber THEN
2423 startnumber = in_startnumber;
2424 endnumber = in_endnumber;
2426 startnumber = in_endnumber;
2427 endnumber = in_startnumber;
2430 numberrange := endnumber - startnumber;
2431 rangestartnumber := startnumber;
2433 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2434 startnumber := startnumber + 1;
2437 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2439 ELSE -- everything else assumed to be 'all'
2444 -- Filter out really broken tiger data
2445 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2446 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2447 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2448 ST_length(linegeo)/(numberrange::float/stepsize::float);
2452 place_centroid := ST_Centroid(linegeo);
2453 partition := get_partition(place_centroid, 'us');
2454 parent_place_id := null;
2456 address_street_word_id := get_name_id(make_standard_name(in_street));
2457 IF address_street_word_id IS NOT NULL THEN
2458 FOR location IN SELECT * from getNearestNamedRoadFeature(partition, place_centroid, address_street_word_id) LOOP
2459 parent_place_id := location.place_id;
2463 IF parent_place_id IS NULL THEN
2464 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(partition, linegeo) LOOP
2465 parent_place_id := location.place_id;
2469 IF parent_place_id IS NULL THEN
2470 FOR location IN SELECT place_id FROM getNearestRoadFeature(partition, place_centroid) LOOP
2471 parent_place_id := location.place_id;
2476 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2477 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2478 values (nextval('seq_place'), partition, parent_place_id, housenum, in_postcode,
2479 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2480 newpoints := newpoints + 1;
2488 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2489 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2494 place_centroid GEOMETRY;
2496 out_parent_place_id BIGINT;
2498 address_street_word_id INTEGER;
2503 place_centroid := ST_Centroid(pointgeo);
2504 partition := get_partition(place_centroid, in_countrycode);
2505 out_parent_place_id := null;
2507 address_street_word_id := get_name_id(make_standard_name(in_street));
2508 IF address_street_word_id IS NOT NULL THEN
2509 FOR location IN SELECT * from getNearestNamedRoadFeature(partition, place_centroid, address_street_word_id) LOOP
2510 out_parent_place_id := location.place_id;
2514 IF out_parent_place_id IS NULL THEN
2515 FOR location IN SELECT place_id FROM getNearestRoadFeature(partition, place_centroid) LOOP
2516 out_parent_place_id := location.place_id;
2520 out_postcode := in_postcode;
2521 IF out_postcode IS NULL THEN
2522 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2524 IF out_postcode IS NULL THEN
2525 out_postcode := getNearestPostcode(partition, place_centroid);
2529 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2530 values (nextval('seq_place'), partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2531 newpoints := newpoints + 1;