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, null, op);
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);
331 result := result | w;
333 words := string_to_array(s, ' ');
334 IF array_upper(words, 1) IS NOT NULL THEN
335 FOR j IN 1..array_upper(words, 1) LOOP
336 IF (words[j] != '') THEN
337 w = getorcreate_word_id(words[j]);
338 IF NOT (ARRAY[w] && result) THEN
339 result := result | w;
345 words := regexp_split_to_array(item.value, E'[,;()]');
346 IF array_upper(words, 1) != 1 THEN
347 FOR j IN 1..array_upper(words, 1) LOOP
348 s := make_standard_name(words[j]);
350 w := getorcreate_word_id(s);
351 IF NOT (ARRAY[w] && result) THEN
352 result := result | w;
358 s := regexp_replace(item.value, '市$', '');
359 IF s != item.value THEN
360 s := make_standard_name(s);
362 w := getorcreate_name_id(s, item.value);
363 IF NOT (ARRAY[w] && result) THEN
364 result := result | w;
374 LANGUAGE plpgsql IMMUTABLE;
376 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
386 result := '{}'::INTEGER[];
388 s := make_standard_name(src);
389 w := getorcreate_name_id(s);
391 IF NOT (ARRAY[w] && result) THEN
392 result := result || w;
395 words := string_to_array(s, ' ');
396 IF array_upper(words, 1) IS NOT NULL THEN
397 FOR j IN 1..array_upper(words, 1) LOOP
398 IF (words[j] != '') THEN
399 w = getorcreate_word_id(words[j]);
400 IF NOT (ARRAY[w] && result) THEN
401 result := result || w;
410 LANGUAGE plpgsql IMMUTABLE;
412 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
419 IF (wordscores is null OR words is null) THEN
424 FOR idxword in 1 .. array_upper(words, 1) LOOP
425 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
426 IF wordscores[idxscores].word = words[idxword] THEN
427 result := result + wordscores[idxscores].score;
435 LANGUAGE plpgsql IMMUTABLE;
437 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
440 place_centre GEOMETRY;
443 place_centre := ST_Centroid(place);
445 --RAISE WARNING 'start: %', ST_AsText(place_centre);
447 -- Try for a OSM polygon first
448 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
450 RETURN nearcountry.country_code;
453 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
455 -- Try for OSM fallback data
456 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
458 RETURN nearcountry.country_code;
461 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
463 -- Natural earth data (first fallback)
464 FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
466 RETURN nearcountry.country_code;
469 -- Natural earth data (first fallback)
470 FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1
472 RETURN nearcountry.country_code;
475 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
477 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
478 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
480 RETURN nearcountry.country_code;
483 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
485 -- Still not in a country - try nearest within ~12 miles of a country
486 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
487 order by st_distance(geometry, place) limit 1
489 RETURN nearcountry.country_code;
495 LANGUAGE plpgsql IMMUTABLE;
497 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
502 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
504 RETURN nearcountry.country_code;
506 RETURN get_country_code(place);
509 LANGUAGE plpgsql IMMUTABLE;
511 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
516 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
518 RETURN lower(nearcountry.country_default_language_code);
523 LANGUAGE plpgsql IMMUTABLE;
525 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
528 place_centre GEOMETRY;
531 FOR nearcountry IN select partition from country_name where country_code = in_country_code
533 RETURN nearcountry.partition;
538 LANGUAGE plpgsql IMMUTABLE;
540 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id INTEGER) RETURNS BOOLEAN
544 DELETE FROM location_area where place_id = OLD_place_id;
545 -- TODO:location_area
551 CREATE OR REPLACE FUNCTION add_location(
553 country_code varchar(2),
557 rank_address INTEGER,
578 IF rank_search > 26 THEN
579 RAISE EXCEPTION 'Adding location with rank > 26 (% rank %)', place_id, rank_search;
582 x := deleteLocationArea(partition, place_id);
585 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
588 centroid := ST_Centroid(geometry);
590 xmin := floor(st_xmin(geometry));
591 xmax := ceil(st_xmax(geometry));
592 ymin := floor(st_ymin(geometry));
593 ymax := ceil(st_ymax(geometry));
595 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
596 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
598 FOR lon IN xmin..(xmax-1) LOOP
599 FOR lat IN ymin..(ymax-1) LOOP
600 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
601 IF st_intersects(geometry, secbox) THEN
602 secgeo := st_intersection(geometry, secbox);
603 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
604 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
611 ELSEIF rank_search < 26 THEN
614 IF rank_search = 14 THEN
616 ELSEIF rank_search = 15 THEN
618 ELSEIF rank_search = 16 THEN
620 ELSEIF rank_search = 17 THEN
622 ELSEIF rank_search = 21 THEN
624 ELSEIF rank_search = 25 THEN
628 secgeo := ST_Buffer(geometry, diameter);
629 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
634 secgeo := ST_Buffer(geometry, 0.0002);
635 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
638 secgeo := ST_Buffer(geometry, 0.001);
639 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
648 CREATE OR REPLACE FUNCTION update_location(
651 place_country_code varchar(2),
654 rank_address INTEGER,
662 b := deleteLocationArea(partition, place_id);
663 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
668 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[])
679 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
680 FOR childplace IN select * from search_name,place_addressline
681 where address_place_id = parent_place_id
682 and search_name.place_id = place_addressline.place_id
684 delete from search_name where place_id = childplace.place_id;
685 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
686 IF childplace.place_id = parent_place_id THEN
687 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
689 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
690 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
691 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
699 CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN
702 newkeywords INTEGER[];
703 addedkeywords INTEGER[];
704 removedkeywords INTEGER[];
708 newkeywords := make_keywords(name);
709 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
710 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
711 where place_id = OLD_place_id into addedkeywords, removedkeywords;
713 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
715 IF #removedkeywords > 0 THEN
716 -- abort due to tokens removed
720 IF #addedkeywords > 0 THEN
721 -- short circuit - no changes
725 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
726 RETURN search_name_add_words(OLD_place_id, addedkeywords);
732 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
744 orginalstartnumber INTEGER;
745 originalnumberrange INTEGER;
748 search_place_id INTEGER;
750 havefirstpoint BOOLEAN;
754 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
756 select nodes from planet_osm_ways where id = wayid INTO waynodes;
757 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
758 IF array_upper(waynodes, 1) IS NOT NULL THEN
760 havefirstpoint := false;
762 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
764 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
765 IF search_place_id IS NULL THEN
766 -- null record of right type
767 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
768 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
770 select * from placex where place_id = search_place_id INTO nextnode;
773 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
775 IF havefirstpoint THEN
777 -- add point to the line string
778 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
779 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
781 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
783 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
785 IF startnumber != endnumber THEN
787 linestr := linestr || ')';
788 --RAISE WARNING 'linestr %',linestr;
789 linegeo := ST_GeomFromText(linestr,4326);
790 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
791 IF (startnumber > endnumber) THEN
792 housenum := endnumber;
793 endnumber := startnumber;
794 startnumber := housenum;
795 linegeo := ST_Reverse(linegeo);
797 orginalstartnumber := startnumber;
798 originalnumberrange := endnumber - startnumber;
800 -- Too much broken data worldwide for this test to be worth using
801 -- IF originalnumberrange > 500 THEN
802 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
805 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
806 startnumber := startnumber + 1;
809 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
810 startnumber := startnumber + 2;
812 ELSE -- everything else assumed to be 'all'
813 startnumber := startnumber + 1;
817 endnumber := endnumber - 1;
818 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
819 FOR housenum IN startnumber..endnumber BY stepsize LOOP
820 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
821 -- ideally postcodes should move up to the way
822 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin,
823 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
824 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin,
825 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));
826 newpoints := newpoints + 1;
827 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
830 havefirstpoint := false;
834 IF NOT havefirstpoint THEN
835 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
836 IF startnumber IS NOT NULL AND startnumber > 0 THEN
837 havefirstpoint := true;
838 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
839 prevnode := nextnode;
841 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
847 --RAISE WARNING 'interpolation points % ',newpoints;
854 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
860 country_code VARCHAR(2);
861 default_language VARCHAR(10);
864 -- RAISE WARNING '%',NEW.osm_id;
867 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
870 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
874 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
875 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
879 IF NEW.osm_type = 'R' THEN
880 -- invalid multipolygons can crash postgis, don't even bother to try!
883 NEW.geometry := ST_buffer(NEW.geometry,0);
884 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
885 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
890 NEW.place_id := nextval('seq_place');
891 NEW.indexed_status := 1; --STATUS_NEW
893 NEW.country_code := get_country_code(NEW.geometry, NEW.country_code);
894 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
895 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
897 -- copy 'name' to or from the default language (if there is a default language)
898 IF NEW.name is not null THEN
899 default_language := get_country_language_code(NEW.country_code);
900 IF default_language IS NOT NULL THEN
901 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
902 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
903 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
904 NEW.name := NEW.name || ('name' => (NEW.name -> 'name:'||default_language));
909 IF NEW.admin_level > 15 THEN
910 NEW.admin_level := 15;
913 IF NEW.housenumber IS NOT NULL THEN
914 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
917 IF NEW.osm_type = 'X' THEN
918 -- E'X'ternal records should already be in the right format so do nothing
920 NEW.rank_search := 30;
921 NEW.rank_address := NEW.rank_search;
923 -- By doing in postgres we have the country available to us - currently only used for postcode
924 IF NEW.class = 'place' THEN
925 IF NEW.type in ('continent') THEN
926 NEW.rank_search := 2;
927 NEW.rank_address := NEW.rank_search;
928 ELSEIF NEW.type in ('sea') THEN
929 NEW.rank_search := 2;
930 NEW.rank_address := 0;
931 ELSEIF NEW.type in ('country') THEN
932 NEW.rank_search := 4;
933 NEW.rank_address := NEW.rank_search;
934 ELSEIF NEW.type in ('state') THEN
935 NEW.rank_search := 8;
936 NEW.rank_address := NEW.rank_search;
937 ELSEIF NEW.type in ('region') THEN
938 NEW.rank_search := 10;
939 NEW.rank_address := NEW.rank_search;
940 ELSEIF NEW.type in ('county') THEN
941 NEW.rank_search := 12;
942 NEW.rank_address := NEW.rank_search;
943 ELSEIF NEW.type in ('city') THEN
944 NEW.rank_search := 16;
945 NEW.rank_address := NEW.rank_search;
946 ELSEIF NEW.type in ('island') THEN
947 NEW.rank_search := 17;
948 NEW.rank_address := 0;
949 ELSEIF NEW.type in ('town') THEN
950 NEW.rank_search := 17;
951 NEW.rank_address := NEW.rank_search;
952 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
953 NEW.rank_search := 18;
954 NEW.rank_address := 17;
955 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
956 NEW.rank_search := 18;
957 NEW.rank_address := 17;
958 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
959 NEW.rank_search := 17;
960 NEW.rank_address := 18;
961 ELSEIF NEW.type in ('moor') THEN
962 NEW.rank_search := 17;
963 NEW.rank_address := 0;
964 ELSEIF NEW.type in ('national_park') THEN
965 NEW.rank_search := 18;
966 NEW.rank_address := 18;
967 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
968 NEW.rank_search := 20;
969 NEW.rank_address := NEW.rank_search;
970 ELSEIF NEW.type in ('farm','locality','islet') THEN
971 NEW.rank_search := 20;
972 NEW.rank_address := 0;
973 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
974 NEW.rank_search := 22;
975 NEW.rank_address := 22;
976 ELSEIF NEW.type in ('postcode') THEN
978 NEW.name := 'ref'=>NEW.postcode;
980 IF NEW.country_code = 'gb' THEN
982 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
983 NEW.rank_search := 25;
984 NEW.rank_address := 5;
985 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
986 NEW.rank_search := 23;
987 NEW.rank_address := 5;
988 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
989 NEW.rank_search := 21;
990 NEW.rank_address := 5;
993 ELSEIF NEW.country_code = 'de' THEN
995 IF NEW.postcode ~ '^([0-9]{5})$' THEN
996 NEW.rank_search := 21;
997 NEW.rank_address := 11;
1001 -- Guess at the postcode format and coverage (!)
1002 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1003 NEW.rank_search := 21;
1004 NEW.rank_address := 11;
1006 -- Does it look splitable into and area and local code?
1007 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1009 IF postcode IS NOT NULL THEN
1010 NEW.rank_search := 25;
1011 NEW.rank_address := 11;
1012 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1013 NEW.rank_search := 21;
1014 NEW.rank_address := 11;
1019 ELSEIF NEW.type in ('airport','street') THEN
1020 NEW.rank_search := 26;
1021 NEW.rank_address := NEW.rank_search;
1022 ELSEIF NEW.type in ('house','building') THEN
1023 NEW.rank_search := 30;
1024 NEW.rank_address := NEW.rank_search;
1025 ELSEIF NEW.type in ('houses') THEN
1026 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1027 -- insert new point into place for each derived building
1028 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1029 NEW.rank_search := 28;
1030 NEW.rank_address := 0;
1033 ELSEIF NEW.class = 'boundary' THEN
1034 NEW.rank_search := NEW.admin_level * 2;
1035 NEW.rank_address := NEW.rank_search;
1036 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1037 NEW.rank_search := 22;
1038 NEW.rank_address := NEW.rank_search;
1039 -- any feature more than 5 square miles is probably worth indexing
1040 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1041 NEW.rank_search := 22;
1042 NEW.rank_address := NEW.rank_search;
1043 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1044 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1046 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1048 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1050 ELSEIF NEW.class = 'waterway' THEN
1051 NEW.rank_address := 17;
1052 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
1053 NEW.rank_search := 27;
1054 NEW.rank_address := NEW.rank_search;
1055 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1056 NEW.rank_search := 26;
1057 NEW.rank_address := NEW.rank_search;
1058 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1059 NEW.rank_search := 4;
1060 NEW.rank_address := NEW.rank_search;
1061 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1063 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1064 NEW.rank_search := 18;
1065 NEW.rank_address := 0;
1070 IF NEW.rank_search > 30 THEN
1071 NEW.rank_search := 30;
1074 IF NEW.rank_address > 30 THEN
1075 NEW.rank_address := 30;
1078 -- Block import below rank 22
1079 -- IF NEW.rank_search > 22 THEN
1084 -- The following is not needed until doing diff updates, and slows the main index process down
1086 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1087 -- Performance: We just can't handle re-indexing for country level changes
1088 IF st_area(NEW.geometry) < 1 THEN
1089 -- mark items within the geometry for re-indexing
1090 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1091 -- work around bug in postgis
1092 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1093 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1094 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1095 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1098 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1100 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1101 IF NEW.type='postcode' THEN
1103 ELSEIF NEW.rank_search < 16 THEN
1105 ELSEIF NEW.rank_search < 18 THEN
1107 ELSEIF NEW.rank_search < 20 THEN
1109 ELSEIF NEW.rank_search = 21 THEN
1111 ELSEIF NEW.rank_search < 24 THEN
1113 ELSEIF NEW.rank_search < 26 THEN
1114 diameter := 0.002; -- 100 to 200 meters
1115 ELSEIF NEW.rank_search < 28 THEN
1116 diameter := 0.001; -- 50 to 100 meters
1118 IF diameter > 0 THEN
1119 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1120 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1125 -- IF NEW.rank_search < 26 THEN
1126 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1135 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1140 place_centroid GEOMETRY;
1142 search_maxdistance FLOAT[];
1143 search_mindistance FLOAT[];
1144 address_havelevel BOOLEAN[];
1145 -- search_scores wordscore[];
1146 -- search_scores_pos INTEGER;
1152 search_diameter FLOAT;
1153 search_prevdiameter FLOAT;
1154 search_maxrank INTEGER;
1155 address_maxrank INTEGER;
1156 address_street_word_id INTEGER;
1157 parent_place_id_count INTEGER;
1161 location_rank_search INTEGER;
1162 location_distance FLOAT;
1166 name_vector INTEGER[];
1167 nameaddress_vector INTEGER[];
1172 --RAISE WARNING '%',NEW.place_id;
1173 --RAISE WARNING '%', NEW;
1175 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1176 -- Silently do nothing
1180 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1182 NEW.indexed_date = now();
1184 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1185 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1189 result := deleteSearchName(NEW.partition, NEW.place_id);
1190 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1191 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1193 -- Adding ourselves to the list simplifies address calculations later
1194 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1196 -- What level are we searching from
1197 search_maxrank := NEW.rank_search;
1199 -- Speed up searches - just use the centroid of the feature
1200 -- cheaper but less acurate
1201 place_centroid := ST_Centroid(NEW.geometry);
1203 -- Initialise the name vector using our name
1204 name_vector := make_keywords(NEW.name);
1205 nameaddress_vector := '{}'::int[];
1207 -- some tag combinations add a special id for search
1208 tagpairid := get_tagpair(NEW.class,NEW.type);
1209 IF tagpairid IS NOT NULL THEN
1210 name_vector := name_vector + tagpairid;
1214 address_havelevel[i] := false;
1217 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1219 -- For low level elements we inherit from our parent road
1220 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1222 --RAISE WARNING 'finding street for %', NEW;
1224 NEW.parent_place_id := null;
1226 -- to do that we have to find our parent road
1227 -- Copy data from linked items (points on ways, addr:street links, relations)
1228 -- Note that addr:street links can only be indexed once the street itself is indexed
1229 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1231 -- Is this node part of a relation?
1232 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1234 -- At the moment we only process one type of relation - associatedStreet
1235 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1236 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1237 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1238 --RAISE WARNING 'node in relation %',relation;
1239 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1240 and rank_search = 26 INTO NEW.parent_place_id;
1246 --RAISE WARNING 'x1';
1247 -- Is this node part of a way?
1248 FOR location IN select * from placex where osm_type = 'W'
1249 and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer])
1251 --RAISE WARNING '%', location;
1252 -- Way IS a road then we are on it - that must be our road
1253 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1254 --RAISE WARNING 'node in way that is a street %',location;
1255 NEW.parent_place_id := location.place_id;
1258 -- Is the WAY part of a relation
1259 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1261 -- At the moment we only process one type of relation - associatedStreet
1262 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1263 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1264 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1265 --RAISE WARNING 'node in way that is in a relation %',relation;
1266 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1267 and rank_search = 26 INTO NEW.parent_place_id;
1273 -- If the way contains an explicit name of a street copy it
1274 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1275 --RAISE WARNING 'node in way that has a streetname %',location;
1276 NEW.street := location.street;
1279 -- If this way is a street interpolation line then it is probably as good as we are going to get
1280 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1281 -- Try and find a way that is close roughly parellel to this line
1282 FOR relation IN SELECT place_id FROM placex
1283 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1284 and st_geometrytype(location.geometry) in ('ST_LineString')
1285 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1286 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1287 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1289 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1290 NEW.parent_place_id := relation.place_id;
1298 --RAISE WARNING 'x2';
1300 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1301 -- Is this way part of a relation?
1302 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1304 -- At the moment we only process one type of relation - associatedStreet
1305 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1306 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1307 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1308 --RAISE WARNING 'way that is in a relation %',relation;
1309 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1310 and rank_search = 26 INTO NEW.parent_place_id;
1317 --RAISE WARNING 'x3';
1319 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1320 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1321 --RAISE WARNING 'street: % %', NEW.street, address_street_word_id;
1322 IF address_street_word_id IS NOT NULL THEN
1323 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1324 --RAISE WARNING 'streetname found nearby %',location;
1325 NEW.parent_place_id := location.place_id;
1330 --RAISE WARNING 'x4';
1332 -- Still nothing, just use the nearest road
1333 -- IF NEW.parent_place_id IS NULL THEN
1334 -- FOR location IN SELECT place_id FROM getNearRoads(NEW.partition, place_centroid) LOOP
1335 -- NEW.parent_place_id := location.place_id;
1339 search_diameter := 0.00005;
1340 WHILE NEW.parent_place_id IS NULL AND search_diameter < 0.1 LOOP
1341 FOR location IN SELECT place_id FROM placex
1342 WHERE ST_DWithin(place_centroid, placex.geometry, search_diameter) and rank_search between 22 and 27
1343 ORDER BY ST_distance(NEW.geometry, placex.geometry) ASC limit 1
1345 NEW.parent_place_id := location.place_id;
1347 search_diameter := search_diameter * 2;
1350 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1352 -- If we didn't find any road fallback to standard method
1353 IF NEW.parent_place_id IS NOT NULL THEN
1355 -- Add the street to the address as zero distance to force to front of list
1356 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1357 address_havelevel[26] := true;
1359 -- Import address details from parent, reclculating distance in process
1360 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
1361 from place_addressline as x join placex on (address_place_id = placex.place_id)
1362 where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1364 -- Get the details of the parent road
1365 select * from search_name where place_id = NEW.parent_place_id INTO location;
1366 NEW.country_code := location.country_code;
1368 --RAISE WARNING '%', NEW.name;
1369 -- If there is no name it isn't searchable, don't bother to create a search record
1370 IF NEW.name is NULL THEN
1374 -- Merge address from parent
1375 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1377 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1378 -- Just be happy with inheriting from parent road only
1379 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid);
1381 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, 0, NEW.country_code,
1382 -- name_vector, nameaddress_vector, place_centroid);
1389 --RAISE WARNING ' INDEXING: %',NEW;
1391 -- convert isin to array of tokenids
1392 isin_tokens := '{}'::int[];
1393 IF NEW.isin IS NOT NULL THEN
1394 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1395 IF array_upper(isin, 1) IS NOT NULL THEN
1396 FOR i IN 1..array_upper(isin, 1) LOOP
1397 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1398 IF address_street_word_id IS NOT NULL THEN
1399 isin_tokens := isin_tokens + address_street_word_id;
1403 isin_tokens := uniq(sort(isin_tokens));
1406 -- Process area matches
1407 location_rank_search := 100;
1408 location_distance := 0;
1409 --RAISE WARNING '%', NEW.partition;
1410 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1412 --RAISE WARNING ' AREA: %',location;
1414 IF location.rank_search < location_rank_search THEN
1415 location_rank_search := location.rank_search;
1416 location_distance := location.distance * 1.5;
1419 IF location.distance < location_distance THEN
1421 -- Add it to the list of search terms
1422 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1423 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1424 address_havelevel[location.rank_address] := true;
1430 -- try using the isin value to find parent places
1431 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1432 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1434 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1435 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1436 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1437 address_havelevel[location.rank_address] := true;
1443 -- if we have a name add this to the name search table
1444 IF NEW.name IS NOT NULL THEN
1446 IF NEW.rank_search <= 26 THEN
1447 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1450 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid);
1452 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1462 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1468 -- mark everything linked to this place for re-indexing
1469 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1470 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1472 -- do the actual delete
1473 b := deleteLocationArea(OLD.partition, OLD.place_id);
1474 b := deleteSearchName(OLD.partition, OLD.place_id);
1475 DELETE FROM place_addressline where place_id = OLD.place_id;
1476 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1484 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1490 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1491 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1498 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1503 existingplacex RECORD;
1504 existinggeometry GEOMETRY;
1505 existingplace_id INTEGER;
1509 IF FALSE AND NEW.osm_type = 'R' THEN
1510 RAISE WARNING '-----------------------------------------------------------------------------------';
1511 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1512 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;
1513 RAISE WARNING '%', existingplacex;
1516 -- Just block these - lots and pointless
1517 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1520 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1524 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
1525 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1529 -- Patch in additional country names
1530 -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1531 IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1532 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1535 -- Have we already done this place?
1536 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;
1538 -- Get the existing place_id
1539 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;
1541 -- Handle a place changing type by removing the old data
1542 -- My generated 'place' types are causing havok because they overlap with real tags
1543 -- TODO: move them to their own special purpose tag to avoid collisions
1544 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1545 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');
1548 -- RAISE WARNING 'Existing: %',existing.place_id;
1550 -- 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
1551 IF existing.osm_type IS NULL
1552 OR existingplacex.osm_type IS NULL
1553 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1554 -- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1555 OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1556 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1559 -- IF existing.osm_type IS NULL THEN
1560 -- RAISE WARNING 'no existing place';
1562 -- IF existingplacex.osm_type IS NULL THEN
1563 -- RAISE WARNING 'no existing placex %', existingplacex;
1567 -- RAISE WARNING 'delete and replace';
1569 IF existing.osm_type IS NOT NULL THEN
1570 -- 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;
1571 IF existing.rank_search < 26 THEN
1572 -- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1574 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1577 -- RAISE WARNING 'delete and replace2';
1579 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1580 insert into placex values (NEW.place_id
1592 ,NEW.parent_place_id
1599 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1604 -- Various ways to do the update
1606 -- Debug, what's changed?
1607 IF FALSE AND existing.rank_search < 26 THEN
1608 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1609 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1611 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1612 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1614 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1615 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1617 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1618 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1620 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1621 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1623 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1624 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1628 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1629 IF existing.geometry != NEW.geometry
1630 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1631 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1634 -- IF existing.rank_search < 26 THEN
1635 -- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1638 -- Get the version of the geometry actually used (in placex table)
1639 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;
1641 -- Performance limit
1642 IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1644 -- 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
1645 update placex set indexed_status = 2 where indexed_status = 0 and
1646 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1647 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1648 AND rank_search > NEW.rank_search;
1650 update placex set indexed_status = 2 where indexed_status = 0 and
1651 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1652 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1653 AND rank_search > NEW.rank_search;
1659 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1660 IF existingplacex.rank_search < 26
1661 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1662 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1663 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1664 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1665 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1666 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1669 -- IF existing.rank_search < 26 THEN
1670 -- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1673 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1675 IF st_area(NEW.geometry) < 0.5 THEN
1676 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1677 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1684 -- Anything else has changed - reindex the lot
1685 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1686 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1687 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1688 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1689 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1690 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1692 -- IF existing.rank_search < 26 THEN
1693 -- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1696 -- performance, can't take the load of re-indexing a whole country / huge area
1697 IF st_area(NEW.geometry) < 0.5 THEN
1698 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1699 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1706 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1707 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1708 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1709 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1710 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1711 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1712 OR existing.geometry != NEW.geometry
1717 housenumber = NEW.housenumber,
1718 street = NEW.street,
1720 postcode = NEW.postcode,
1721 country_code = NEW.country_code,
1722 parent_place_id = null,
1723 geometry = NEW.geometry
1724 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1728 housenumber = NEW.housenumber,
1729 street = NEW.street,
1731 postcode = NEW.postcode,
1732 country_code = NEW.country_code,
1733 parent_place_id = null,
1735 geometry = NEW.geometry
1736 where place_id = existingplacex.place_id;
1738 result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1742 -- Abort the add (we modified the existing place instead)
1746 $$ LANGUAGE plpgsql;
1748 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1755 IF name is null THEN
1759 search := languagepref;
1761 FOR j IN 1..array_upper(search, 1) LOOP
1762 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1763 return trim(name->search[j]);
1770 LANGUAGE plpgsql IMMUTABLE;
1772 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1775 searchnodes INTEGER[];
1780 searchnodes := '{}';
1781 FOR j IN 1..array_upper(way_ids, 1) LOOP
1783 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1785 searchnodes := searchnodes | location.nodes;
1789 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1792 LANGUAGE plpgsql IMMUTABLE;
1794 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT
1805 search := ARRAY['ref'];
1808 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1811 select rank_address,name,distance,length(name::text) as namelength
1812 from place_addressline join placex on (address_place_id = placex.place_id)
1813 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1814 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1816 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1817 FOR j IN 1..array_upper(search, 1) LOOP
1818 FOR k IN 1..array_upper(location.name, 1) LOOP
1819 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
1820 result[(100 - location.rank_address)] := trim(location.name[k].value);
1821 found := location.rank_address;
1828 RETURN array_to_string(result,', ');
1833 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT
1840 searchcountrycode varchar(2);
1841 searchhousenumber TEXT;
1842 searchrankaddress INTEGER;
1846 search := languagepref;
1849 select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress;
1852 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1853 CASE WHEN type = 'postcode' THEN 'name' => postcode ELSE name END as name,
1854 distance,length(name::text) as namelength
1855 from place_addressline join placex on (address_place_id = placex.place_id)
1856 where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
1857 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1858 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1860 IF array_upper(search, 1) IS NOT NULL AND location.name IS NOT NULL THEN
1861 FOR j IN 1..array_upper(search, 1) LOOP
1862 IF (found > location.rank_address AND location.name ? search[j] AND location.name -> search[j] != ''
1863 AND NOT result && ARRAY[location.name -> search[j]]) THEN
1864 result[(100 - location.rank_address)] := trim(location.name -> search[j]);
1865 found := location.rank_address;
1871 IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
1872 IF result[(100 - 28)] IS NOT NULL THEN
1873 result[(100 - 29)] := result[(100 - 28)];
1875 result[(100 - 28)] := searchhousenumber;
1878 -- No country polygon - add it from the country_code
1880 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1881 where place_id = for_place_id limit 1 INTO location;
1882 IF location IS NOT NULL THEN
1883 result[(100 - 4)] := trim(location.name);
1887 RETURN array_to_string(result,', ');
1892 CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT[]
1899 searchcountrycode varchar(2);
1900 searchhousenumber TEXT;
1904 search := languagepref;
1907 UPDATE placex set indexed_status = 0 where indexed_status > 0 and place_id = for_place_id;
1909 select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
1912 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1913 name,distance,length(name::text) as namelength
1914 from place_addressline join placex on (address_place_id = placex.place_id)
1915 where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
1916 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1917 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1919 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1920 FOR j IN 1..array_upper(search, 1) LOOP
1921 FOR k IN 1..array_upper(location.name, 1) LOOP
1922 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)] THEN
1923 result[(100 - location.rank_address)] := trim(location.name[k].value);
1924 found := location.rank_address;
1931 IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
1932 result[(100 - 28)] := searchhousenumber;
1935 -- No country polygon - add it from the country_code
1937 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1938 where place_id = for_place_id limit 1 INTO location;
1939 IF location IS NOT NULL THEN
1940 result[(100 - 4)] := trim(location.name);
1949 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
1952 result place_boundingbox;
1953 numfeatures integer;
1955 select * from place_boundingbox into result where place_id = search_place_id;
1956 IF result.place_id IS NULL THEN
1957 -- remove isaddress = true because if there is a matching polygon it always wins
1958 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
1959 insert into place_boundingbox select place_id,
1960 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
1961 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
1962 numfeatures, ST_Area(geometry),
1963 geometry as area from location_area where place_id = search_place_id;
1964 select * from place_boundingbox into result where place_id = search_place_id;
1966 IF result.place_id IS NULL THEN
1968 insert into place_boundingbox select address_place_id,
1969 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
1970 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
1971 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
1972 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
1973 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)
1974 where address_place_id = search_place_id
1975 -- and (isaddress = true OR place_id = search_place_id)
1976 and (st_length(geometry) < 0.01 or place_id = search_place_id)
1977 group by address_place_id limit 1;
1978 select * from place_boundingbox into result where place_id = search_place_id;
1985 -- don't do the operation if it would be slow
1986 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
1989 result place_boundingbox;
1990 numfeatures integer;
1993 select * from place_boundingbox into result where place_id = search_place_id;
1994 IF result IS NULL AND rank > 14 THEN
1995 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
1996 insert into place_boundingbox select place_id,
1997 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
1998 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
1999 numfeatures, ST_Area(geometry),
2000 geometry as area from location_area where place_id = search_place_id;
2001 select * from place_boundingbox into result where place_id = search_place_id;
2003 IF result IS NULL THEN
2004 select rank_search from placex where place_id = search_place_id into rank;
2007 insert into place_boundingbox select address_place_id,
2008 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2009 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2010 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2011 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2012 from place_addressline join placex using (place_id)
2013 where address_place_id = search_place_id
2014 and (isaddress = true OR place_id = search_place_id)
2015 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2016 group by address_place_id limit 1;
2017 select * from place_boundingbox into result where place_id = search_place_id;
2025 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2028 result place_boundingbox;
2029 numfeatures integer;
2033 housenumber = place.housenumber,
2034 street = place.street,
2036 postcode = place.postcode,
2037 country_code = place.country_code,
2038 parent_place_id = null,
2041 where placex.place_id = search_place_id
2042 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2043 and place.class = placex.class and place.type = placex.type;
2044 update placex set indexed_status = 0 where place_id = search_place_id;
2050 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2053 result place_boundingbox;
2054 numfeatures integer;
2058 housenumber = place.housenumber,
2059 street = place.street,
2061 postcode = place.postcode,
2062 country_code = place.country_code,
2063 parent_place_id = null,
2066 where placex.place_id = search_place_id
2067 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2068 and place.class = placex.class and place.type = placex.type;
2069 update placex set indexed_status = 0 where place_id = search_place_id;
2075 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2081 ELSEIF rank < 4 THEN
2083 ELSEIF rank < 8 THEN
2085 ELSEIF rank < 12 THEN
2087 ELSEIF rank < 16 THEN
2089 ELSEIF rank = 16 THEN
2091 ELSEIF rank = 17 THEN
2092 RETURN 'Town / Island';
2093 ELSEIF rank = 18 THEN
2094 RETURN 'Village / Hamlet';
2095 ELSEIF rank = 20 THEN
2097 ELSEIF rank = 21 THEN
2098 RETURN 'Postcode Area';
2099 ELSEIF rank = 22 THEN
2100 RETURN 'Croft / Farm / Locality / Islet';
2101 ELSEIF rank = 23 THEN
2102 RETURN 'Postcode Area';
2103 ELSEIF rank = 25 THEN
2104 RETURN 'Postcode Point';
2105 ELSEIF rank = 26 THEN
2106 RETURN 'Street / Major Landmark';
2107 ELSEIF rank = 27 THEN
2108 RETURN 'Minory Street / Path';
2109 ELSEIF rank = 28 THEN
2110 RETURN 'House / Building';
2112 RETURN 'Other: '||rank;
2119 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2125 ELSEIF rank < 2 THEN
2127 ELSEIF rank < 4 THEN
2129 ELSEIF rank = 5 THEN
2131 ELSEIF rank < 8 THEN
2133 ELSEIF rank < 12 THEN
2135 ELSEIF rank < 16 THEN
2137 ELSEIF rank = 16 THEN
2139 ELSEIF rank = 17 THEN
2140 RETURN 'Town / Village / Hamlet';
2141 ELSEIF rank = 20 THEN
2143 ELSEIF rank = 21 THEN
2144 RETURN 'Postcode Area';
2145 ELSEIF rank = 22 THEN
2146 RETURN 'Croft / Farm / Locality / Islet';
2147 ELSEIF rank = 23 THEN
2148 RETURN 'Postcode Area';
2149 ELSEIF rank = 25 THEN
2150 RETURN 'Postcode Point';
2151 ELSEIF rank = 26 THEN
2152 RETURN 'Street / Major Landmark';
2153 ELSEIF rank = 27 THEN
2154 RETURN 'Minory Street / Path';
2155 ELSEIF rank = 28 THEN
2156 RETURN 'House / Building';
2158 RETURN 'Other: '||rank;
2165 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2172 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2173 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2180 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2188 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2190 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2191 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2193 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2201 CREATE AGGREGATE array_agg(INT[])