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(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 (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 geometry_index(place geometry, indexed BOOLEAN, name HSTORE) RETURNS INTEGER
91 IF indexed THEN RETURN NULL; END IF;
92 IF name is null THEN RETURN NULL; END IF;
93 RETURN geometry_sector(place);
96 LANGUAGE plpgsql IMMUTABLE;
98 CREATE OR REPLACE FUNCTION geometry_index(sector integer, indexed BOOLEAN, name HSTORE) RETURNS INTEGER
101 IF indexed THEN RETURN NULL; END IF;
102 IF name is null THEN RETURN NULL; END IF;
106 LANGUAGE plpgsql IMMUTABLE;
108 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
109 AS '{modulepath}/nominatim.so', 'transliteration'
110 LANGUAGE c IMMUTABLE STRICT;
112 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
113 AS '{modulepath}/nominatim.so', 'gettokenstring'
114 LANGUAGE c IMMUTABLE STRICT;
116 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
121 o := gettokenstring(transliteration(name));
122 RETURN trim(substr(o,1,length(o)));
125 LANGUAGE 'plpgsql' IMMUTABLE;
127 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
132 return_word_id INTEGER;
134 lookup_token := trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 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);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
168 return_word_id INTEGER;
170 lookup_token := ' '||trim(lookup_word);
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := ' '||trim(lookup_word);
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
190 IF return_word_id IS NULL THEN
191 return_word_id := nextval('seq_word');
192 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
194 RETURN return_word_id;
199 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
204 return_word_id INTEGER;
206 lookup_token := lookup_class||'='||lookup_type;
207 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
208 IF return_word_id IS NULL THEN
209 return_word_id := nextval('seq_word');
210 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
212 RETURN return_word_id;
217 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
222 return_word_id INTEGER;
224 lookup_token := lookup_class||'='||lookup_type;
225 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
226 RETURN return_word_id;
231 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
236 return_word_id INTEGER;
238 lookup_token := ' '||trim(lookup_word);
239 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;
240 IF return_word_id IS NULL THEN
241 return_word_id := nextval('seq_word');
242 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null, op);
244 RETURN return_word_id;
249 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
254 nospace_lookup_token TEXT;
255 return_word_id INTEGER;
257 lookup_token := ' '||trim(lookup_word);
258 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
259 IF return_word_id IS NULL THEN
260 return_word_id := nextval('seq_word');
261 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);
262 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
263 -- IF ' '||nospace_lookup_token != lookup_token THEN
264 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
267 RETURN return_word_id;
272 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
277 RETURN getorcreate_name_id(lookup_word, '');
282 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
287 return_word_id INTEGER;
289 lookup_token := trim(lookup_word);
290 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
291 RETURN return_word_id;
294 LANGUAGE plpgsql IMMUTABLE;
296 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
301 return_word_id INTEGER;
303 lookup_token := ' '||trim(lookup_word);
304 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
305 RETURN return_word_id;
308 LANGUAGE plpgsql IMMUTABLE;
310 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
317 IF array_upper(a, 1) IS NULL THEN
320 IF array_upper(b, 1) IS NULL THEN
324 FOR i IN 1..array_upper(b, 1) LOOP
325 IF NOT (ARRAY[b[i]] && r) THEN
332 LANGUAGE plpgsql IMMUTABLE;
334 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
344 result := '{}'::INTEGER[];
346 FOR item IN SELECT (each(src)).* LOOP
348 s := make_standard_name(item.value);
350 w := getorcreate_name_id(s, item.value);
351 result := result | w;
353 words := string_to_array(s, ' ');
354 IF array_upper(words, 1) IS NOT NULL THEN
355 FOR j IN 1..array_upper(words, 1) LOOP
356 IF (words[j] != '') THEN
357 w = getorcreate_word_id(words[j]);
358 IF NOT (ARRAY[w] && result) THEN
359 result := result | w;
365 words := regexp_split_to_array(item.value, E'[,;()]');
366 IF array_upper(words, 1) != 1 THEN
367 FOR j IN 1..array_upper(words, 1) LOOP
368 s := make_standard_name(words[j]);
370 w := getorcreate_word_id(s);
371 IF NOT (ARRAY[w] && result) THEN
372 result := result | w;
378 s := regexp_replace(item.value, '市$', '');
379 IF s != item.value THEN
380 s := make_standard_name(s);
382 w := getorcreate_name_id(s, item.value);
383 IF NOT (ARRAY[w] && result) THEN
384 result := result | w;
394 LANGUAGE plpgsql IMMUTABLE;
396 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
406 result := '{}'::INTEGER[];
408 s := make_standard_name(src);
409 w := getorcreate_name_id(s);
411 IF NOT (ARRAY[w] && result) THEN
412 result := result || w;
415 words := string_to_array(s, ' ');
416 IF array_upper(words, 1) IS NOT NULL THEN
417 FOR j IN 1..array_upper(words, 1) LOOP
418 IF (words[j] != '') THEN
419 w = getorcreate_word_id(words[j]);
420 IF NOT (ARRAY[w] && result) THEN
421 result := result || w;
430 LANGUAGE plpgsql IMMUTABLE;
432 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
439 IF (wordscores is null OR words is null) THEN
444 FOR idxword in 1 .. array_upper(words, 1) LOOP
445 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
446 IF wordscores[idxscores].word = words[idxword] THEN
447 result := result + wordscores[idxscores].score;
455 LANGUAGE plpgsql IMMUTABLE;
457 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
460 place_centre GEOMETRY;
463 place_centre := ST_Centroid(place);
465 --RAISE WARNING 'start: %', ST_AsText(place_centre);
467 -- Try for a OSM polygon first
468 FOR nearcountry IN select country_code from location_area_country where country_code is not null and st_contains(geometry, place_centre) limit 1
470 RETURN nearcountry.country_code;
473 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
475 -- Try for OSM fallback data
476 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
478 RETURN nearcountry.country_code;
481 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
483 -- Natural earth data (first fallback)
484 -- FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
486 -- RETURN nearcountry.country_code;
489 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
491 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
492 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
494 RETURN nearcountry.country_code;
497 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
499 -- Still not in a country - try nearest within ~12 miles of a country
500 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
501 order by st_distance(geometry, place) limit 1
503 RETURN nearcountry.country_code;
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 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 delete_location(OLD_place_id INTEGER) RETURNS BOOLEAN
529 DELETE FROM location_area where place_id = OLD_place_id;
530 -- TODO:location_area
536 CREATE OR REPLACE FUNCTION add_location(
538 place_country_code varchar(2),
541 rank_address INTEGER,
548 country_code VARCHAR(2);
549 partition VARCHAR(10);
564 -- Allocate all tokens ids - prevents multi-processor race condition later on at cost of slowing down import
565 keywords := make_keywords(name);
567 -- 26 = street/highway
568 IF rank_search <= 26 THEN
569 IF place_country_code IS NULL THEN
570 country_code := get_country_code(geometry);
572 country_code := lower(place_country_code);
573 partition := country_code;
574 IF partition is null THEN
579 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
582 centroid := ST_Centroid(geometry);
584 xmin := floor(st_xmin(geometry));
585 xmax := ceil(st_xmax(geometry));
586 ymin := floor(st_ymin(geometry));
587 ymax := ceil(st_ymax(geometry));
589 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
590 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
592 FOR lon IN xmin..(xmax-1) LOOP
593 FOR lat IN ymin..(ymax-1) LOOP
594 secgeo := st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326));
595 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
596 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
602 ELSEIF rank_search < 26 THEN
605 IF rank_search = 14 THEN
607 ELSEIF rank_search = 15 THEN
609 ELSEIF rank_search = 16 THEN
611 ELSEIF rank_search = 17 THEN
613 ELSEIF rank_search = 25 THEN
617 secgeo := ST_Buffer(geometry, diameter);
618 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, ST_Centroid(geometry), secgeo);
623 secgeo := ST_Buffer(geometry, 0.0002);
624 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, false, ST_Centroid(geometry), secgeo);
627 secgeo := ST_Buffer(geometry, 0.001);
628 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, false, ST_Centroid(geometry), secgeo);
641 CREATE OR REPLACE FUNCTION update_location(
643 place_country_code varchar(2),
646 rank_address INTEGER,
654 b := delete_location(place_id);
655 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
660 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[])
671 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
672 FOR childplace IN select * from search_name,place_addressline
673 where address_place_id = parent_place_id
674 and search_name.place_id = place_addressline.place_id
676 delete from search_name where place_id = childplace.place_id;
677 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
678 IF childplace.place_id = parent_place_id THEN
679 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
681 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
682 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
683 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
691 CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN
694 newkeywords INTEGER[];
695 addedkeywords INTEGER[];
696 removedkeywords INTEGER[];
700 newkeywords := make_keywords(name);
701 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
702 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
703 where place_id = OLD_place_id into addedkeywords, removedkeywords;
705 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
707 IF #removedkeywords > 0 THEN
708 -- abort due to tokens removed
712 IF #addedkeywords > 0 THEN
713 -- short circuit - no changes
717 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
718 RETURN search_name_add_words(OLD_place_id, addedkeywords);
724 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
736 orginalstartnumber INTEGER;
737 originalnumberrange INTEGER;
740 search_place_id INTEGER;
742 havefirstpoint BOOLEAN;
746 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
748 select nodes from planet_osm_ways where id = wayid INTO waynodes;
749 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
750 IF array_upper(waynodes, 1) IS NOT NULL THEN
752 havefirstpoint := false;
754 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
756 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
757 IF search_place_id IS NULL THEN
758 -- null record of right type
759 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
760 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
762 select * from placex where place_id = search_place_id INTO nextnode;
765 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
767 IF havefirstpoint THEN
769 -- add point to the line string
770 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
771 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
773 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
775 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
777 IF startnumber != endnumber THEN
779 linestr := linestr || ')';
780 --RAISE WARNING 'linestr %',linestr;
781 linegeo := ST_GeomFromText(linestr,4326);
782 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
783 IF (startnumber > endnumber) THEN
784 housenum := endnumber;
785 endnumber := startnumber;
786 startnumber := housenum;
787 linegeo := ST_Reverse(linegeo);
789 orginalstartnumber := startnumber;
790 originalnumberrange := endnumber - startnumber;
792 -- Too much broken data worldwide for this test to be worth using
793 -- IF originalnumberrange > 500 THEN
794 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
797 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
798 startnumber := startnumber + 1;
801 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
802 startnumber := startnumber + 2;
804 ELSE -- everything else assumed to be 'all'
805 startnumber := startnumber + 1;
809 endnumber := endnumber - 1;
810 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
811 FOR housenum IN startnumber..endnumber BY stepsize LOOP
812 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
813 -- ideally postcodes should move up to the way
814 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin,
815 country_code, street_place_id, rank_address, rank_search, indexed_status, geometry)
816 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin,
817 prevnode.country_code, prevnode.street_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
818 newpoints := newpoints + 1;
819 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
822 havefirstpoint := false;
826 IF NOT havefirstpoint THEN
827 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
828 IF startnumber IS NOT NULL AND startnumber > 0 THEN
829 havefirstpoint := true;
830 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
831 prevnode := nextnode;
833 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
839 --RAISE WARNING 'interpolation points % ',newpoints;
846 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
852 country_code VARCHAR(2);
855 -- RAISE WARNING '%',NEW.osm_id;
858 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
861 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
865 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
866 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
870 IF NEW.osm_type = 'R' THEN
871 -- invalid multipolygons can crash postgis, don't even bother to try!
874 NEW.geometry := ST_buffer(NEW.geometry,0);
875 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
876 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
881 NEW.place_id := nextval('seq_place');
882 NEW.indexed_status := 1;
883 NEW.country_code := lower(NEW.country_code);
884 IF NEW.country_code is null THEN
885 NEW.country_code := get_country_code(NEW.geometry);
887 NEW.geometry_sector := geometry_sector(NEW.geometry);
889 IF NEW.admin_level > 15 THEN
890 NEW.admin_level := 15;
893 IF NEW.housenumber IS NOT NULL THEN
894 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
897 IF NEW.osm_type = 'X' THEN
898 -- E'X'ternal records should already be in the right format so do nothing
900 NEW.rank_search := 30;
901 NEW.rank_address := NEW.rank_search;
903 -- By doing in postgres we have the country available to us - currently only used for postcode
904 IF NEW.class = 'place' THEN
905 IF NEW.type in ('continent') THEN
906 NEW.rank_search := 2;
907 NEW.rank_address := NEW.rank_search;
908 ELSEIF NEW.type in ('sea') THEN
909 NEW.rank_search := 2;
910 NEW.rank_address := 0;
911 ELSEIF NEW.type in ('country') THEN
912 NEW.rank_search := 4;
913 NEW.rank_address := NEW.rank_search;
914 ELSEIF NEW.type in ('state') THEN
915 NEW.rank_search := 8;
916 NEW.rank_address := NEW.rank_search;
917 ELSEIF NEW.type in ('region') THEN
918 NEW.rank_search := 10;
919 NEW.rank_address := NEW.rank_search;
920 ELSEIF NEW.type in ('county') THEN
921 NEW.rank_search := 12;
922 NEW.rank_address := NEW.rank_search;
923 ELSEIF NEW.type in ('city') THEN
924 NEW.rank_search := 16;
925 NEW.rank_address := NEW.rank_search;
926 ELSEIF NEW.type in ('island') THEN
927 NEW.rank_search := 17;
928 NEW.rank_address := 0;
929 ELSEIF NEW.type in ('town') THEN
930 NEW.rank_search := 17;
931 NEW.rank_address := NEW.rank_search;
932 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
933 NEW.rank_search := 18;
934 NEW.rank_address := 17;
935 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
936 NEW.rank_search := 18;
937 NEW.rank_address := 17;
938 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
939 NEW.rank_search := 17;
940 NEW.rank_address := 18;
941 ELSEIF NEW.type in ('moor') THEN
942 NEW.rank_search := 17;
943 NEW.rank_address := 0;
944 ELSEIF NEW.type in ('national_park') THEN
945 NEW.rank_search := 18;
946 NEW.rank_address := 18;
947 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
948 NEW.rank_search := 20;
949 NEW.rank_address := NEW.rank_search;
950 ELSEIF NEW.type in ('farm','locality','islet') THEN
951 NEW.rank_search := 20;
952 NEW.rank_address := 0;
953 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
954 NEW.rank_search := 22;
955 NEW.rank_address := 22;
956 ELSEIF NEW.type in ('postcode') THEN
958 -- Postcode processing is very country dependant
959 IF NEW.country_code IS NULL THEN
962 NEW.name := 'ref'=>NEW.postcode;
964 IF NEW.country_code = 'gb' THEN
966 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
967 NEW.rank_search := 25;
968 NEW.rank_address := 5;
969 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
970 NEW.rank_search := 23;
971 NEW.rank_address := 5;
972 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
973 NEW.rank_search := 21;
974 NEW.rank_address := 5;
977 ELSEIF NEW.country_code = 'de' THEN
979 IF NEW.postcode ~ '^([0-9]{5})$' THEN
980 NEW.rank_search := 21;
981 NEW.rank_address := 11;
985 -- Guess at the postcode format and coverage (!)
986 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
987 NEW.rank_search := 21;
988 NEW.rank_address := 11;
990 -- Does it look splitable into and area and local code?
991 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
993 IF postcode IS NOT NULL THEN
994 NEW.rank_search := 25;
995 NEW.rank_address := 11;
996 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
997 NEW.rank_search := 21;
998 NEW.rank_address := 11;
1003 ELSEIF NEW.type in ('airport','street') THEN
1004 NEW.rank_search := 26;
1005 NEW.rank_address := NEW.rank_search;
1006 ELSEIF NEW.type in ('house','building') THEN
1007 NEW.rank_search := 30;
1008 NEW.rank_address := NEW.rank_search;
1009 ELSEIF NEW.type in ('houses') THEN
1010 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1011 -- insert new point into place for each derived building
1012 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1013 NEW.rank_search := 28;
1014 NEW.rank_address := 0;
1017 ELSEIF NEW.class = 'boundary' THEN
1018 NEW.rank_search := NEW.admin_level * 2;
1019 NEW.rank_address := NEW.rank_search;
1020 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1021 NEW.rank_search := 22;
1022 NEW.rank_address := NEW.rank_search;
1023 -- any feature more than 5 square miles is probably worth indexing
1024 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1025 NEW.rank_search := 22;
1026 NEW.rank_address := NEW.rank_search;
1027 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1028 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1030 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1032 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1034 ELSEIF NEW.class = 'waterway' THEN
1035 NEW.rank_address := 17;
1036 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
1037 NEW.rank_search := 27;
1038 NEW.rank_address := NEW.rank_search;
1039 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1040 NEW.rank_search := 26;
1041 NEW.rank_address := NEW.rank_search;
1042 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1043 NEW.rank_search := 4;
1044 NEW.rank_address := NEW.rank_search;
1045 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1047 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1048 NEW.rank_search := 18;
1049 NEW.rank_address := 0;
1054 IF NEW.rank_search > 30 THEN
1055 NEW.rank_search := 30;
1058 IF NEW.rank_address > 30 THEN
1059 NEW.rank_address := 30;
1062 -- Block import below rank 22
1063 -- IF NEW.rank_search > 22 THEN
1067 IF NEW.name is not null THEN
1068 result := add_location(NEW.place_id,NEW.country_code,NEW.name,NEW.rank_search,NEW.rank_address,NEW.geometry);
1072 -- The following is not needed until doing diff updates, and slows the main index process down
1074 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1075 -- Performance: We just can't handle re-indexing for country level changes
1076 IF st_area(NEW.geometry) < 1 THEN
1077 -- mark items within the geometry for re-indexing
1078 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1079 -- work around bug in postgis
1080 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1081 AND rank_search > NEW.rank_search and indexed = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1082 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1083 AND rank_search > NEW.rank_search and indexed = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1086 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1088 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1089 IF NEW.type='postcode' THEN
1091 ELSEIF NEW.rank_search < 16 THEN
1093 ELSEIF NEW.rank_search < 18 THEN
1095 ELSEIF NEW.rank_search < 20 THEN
1097 ELSEIF NEW.rank_search = 21 THEN
1099 ELSEIF NEW.rank_search < 24 THEN
1101 ELSEIF NEW.rank_search < 26 THEN
1102 diameter := 0.002; -- 100 to 200 meters
1103 ELSEIF NEW.rank_search < 28 THEN
1104 diameter := 0.001; -- 50 to 100 meters
1106 IF diameter > 0 THEN
1107 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1108 update placex set indexed = 2 where indexed and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1113 -- IF NEW.rank_search < 26 THEN
1114 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1123 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1128 place_centroid GEOMETRY;
1130 search_maxdistance FLOAT[];
1131 search_mindistance FLOAT[];
1132 address_havelevel BOOLEAN[];
1133 -- search_scores wordscore[];
1134 -- search_scores_pos INTEGER;
1140 search_diameter FLOAT;
1141 search_prevdiameter FLOAT;
1142 search_maxrank INTEGER;
1143 address_maxrank INTEGER;
1144 address_street_word_id INTEGER;
1145 street_place_id_count INTEGER;
1149 location_rank_search INTEGER;
1150 location_distance FLOAT;
1154 name_vector INTEGER[];
1155 nameaddress_vector INTEGER[];
1160 --RAISE WARNING '%',NEW.place_id;
1161 --RAISE WARNING '%', NEW;
1163 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1164 -- Silently do nothing
1168 IF NEW.country_code is null THEN
1169 NEW.country_code := get_country_code(NEW.geometry);
1171 NEW.country_code := lower(NEW.country_code);
1172 NEW.partition := NEW.country_code;
1173 IF NEW.partition is null THEN
1174 NEW.partition := 'none';
1177 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1179 NEW.indexed_date = now();
1181 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1182 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1186 DELETE FROM search_name WHERE place_id = NEW.place_id;
1187 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1188 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1190 -- Adding ourselves to the list simplifies address calculations later
1191 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1193 -- What level are we searching from
1194 search_maxrank := NEW.rank_search;
1196 -- Speed up searches - just use the centroid of the feature
1197 -- cheaper but less acurate
1198 place_centroid := ST_Centroid(NEW.geometry);
1200 -- Initialise the name vector using our name
1201 name_vector := make_keywords(NEW.name);
1202 nameaddress_vector := '{}'::int[];
1204 -- some tag combinations add a special id for search
1205 tagpairid := get_tagpair(NEW.class,NEW.type);
1206 IF tagpairid IS NOT NULL THEN
1207 name_vector := name_vector + tagpairid;
1210 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1212 -- For low level elements we inherit from our parent road
1213 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1215 --RAISE WARNING 'finding street for %', NEW;
1217 NEW.street_place_id := null;
1219 -- to do that we have to find our parent road
1220 -- Copy data from linked items (points on ways, addr:street links, relations)
1221 -- Note that addr:street links can only be indexed once the street itself is indexed
1222 IF NEW.street_place_id IS NULL AND NEW.osm_type = 'N' THEN
1224 -- Is this node part of a relation?
1225 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1227 -- At the moment we only process one type of relation - associatedStreet
1228 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1229 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1230 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1231 --RAISE WARNING 'node in relation %',relation;
1232 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1233 and rank_search = 26 INTO NEW.street_place_id;
1239 --RAISE WARNING 'x1';
1240 -- Is this node part of a way?
1241 FOR location IN select * from placex where osm_type = 'W'
1242 and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer])
1244 --RAISE WARNING '%', location;
1245 -- Way IS a road then we are on it - that must be our road
1246 IF location.rank_search = 26 AND NEW.street_place_id IS NULL THEN
1247 --RAISE WARNING 'node in way that is a street %',location;
1248 NEW.street_place_id := location.place_id;
1251 -- Is the WAY part of a relation
1252 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1254 -- At the moment we only process one type of relation - associatedStreet
1255 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1256 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1257 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1258 --RAISE WARNING 'node in way that is in a relation %',relation;
1259 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1260 and rank_search = 26 INTO NEW.street_place_id;
1266 -- If the way contains an explicit name of a street copy it
1267 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1268 --RAISE WARNING 'node in way that has a streetname %',location;
1269 NEW.street := location.street;
1272 -- If this way is a street interpolation line then it is probably as good as we are going to get
1273 IF NEW.street_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1274 -- Try and find a way that is close roughly parellel to this line
1275 FOR relation IN SELECT place_id FROM placex
1276 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1277 and st_geometrytype(location.geometry) in ('ST_LineString')
1278 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1279 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1280 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1282 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1283 NEW.street_place_id := relation.place_id;
1291 --RAISE WARNING 'x2';
1293 IF NEW.street_place_id IS NULL AND NEW.osm_type = 'W' THEN
1294 -- Is this way part of a relation?
1295 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1297 -- At the moment we only process one type of relation - associatedStreet
1298 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1299 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1300 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1301 --RAISE WARNING 'way that is in a relation %',relation;
1302 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1303 and rank_search = 26 INTO NEW.street_place_id;
1310 --RAISE WARNING 'x3';
1312 IF NEW.street_place_id IS NULL AND NEW.street IS NOT NULL THEN
1313 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1314 --RAISE WARNING 'street: % %', NEW.street, address_street_word_id;
1315 IF address_street_word_id IS NOT NULL THEN
1316 FOR location IN SELECT place_id,ST_distance(NEW.geometry, search_name.centroid) as distance
1317 FROM search_name WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1318 AND ST_DWithin(NEW.geometry, search_name.centroid, 0.01) and search_rank between 22 and 27
1319 ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1321 --RAISE WARNING 'streetname found nearby %',location;
1322 NEW.street_place_id := location.place_id;
1325 -- Failed, fall back to nearest - don't just stop
1326 IF NEW.street_place_id IS NULL THEN
1327 --RAISE WARNING 'unable to find streetname nearby % %',NEW.street,address_street_word_id;
1332 --RAISE WARNING 'x4';
1334 IF NEW.street_place_id IS NULL THEN
1335 FOR location IN SELECT place_id FROM getNearRoads(NEW.partition, place_centroid) LOOP
1336 NEW.street_place_id := location.place_id;
1340 --RAISE WARNING 'x6 %',NEW.street_place_id;
1342 -- If we didn't find any road fallback to standard method
1343 IF NEW.street_place_id IS NOT NULL THEN
1345 -- Some unnamed roads won't have been indexed, index now if needed
1346 -- ALL are now indexed!
1347 -- select count(*) from place_addressline where place_id = NEW.street_place_id INTO street_place_id_count;
1348 -- IF street_place_id_count = 0 THEN
1349 -- UPDATE placex set indexed = true where indexed = false and place_id = NEW.street_place_id;
1352 -- Add the street to the address as zero distance to force to front of list
1353 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.street_place_id, true, true, 0, 26);
1354 address_havelevel[26] := true;
1356 -- Import address details from parent, reclculating distance in process
1357 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
1358 from place_addressline as x join placex on (address_place_id = placex.place_id)
1359 where x.place_id = NEW.street_place_id and x.address_place_id != NEW.street_place_id;
1361 -- Get the details of the parent road
1362 select * from search_name where place_id = NEW.street_place_id INTO location;
1363 NEW.country_code := location.country_code;
1365 --RAISE WARNING '%', NEW.name;
1366 -- If there is no name it isn't searchable, don't bother to create a search record
1367 IF NEW.name is NULL THEN
1371 -- Merge address from parent
1372 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1374 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1375 -- Just be happy with inheriting from parent road only
1376 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, NEW.country_code,
1377 name_vector, nameaddress_vector, place_centroid);
1384 --RAISE WARNING ' INDEXING: %',NEW;
1386 -- convert isin to array of tokenids
1387 isin_tokens := '{}'::int[];
1388 IF NEW.isin IS NOT NULL THEN
1389 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1390 IF array_upper(isin, 1) IS NOT NULL THEN
1391 FOR i IN 1..array_upper(isin, 1) LOOP
1392 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1393 IF address_street_word_id IS NOT NULL THEN
1394 isin_tokens := isin_tokens + address_street_word_id;
1398 isin_tokens := uniq(sort(isin_tokens));
1401 -- Process area matches
1402 location_rank_search := 100;
1403 location_distance := 0;
1404 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1406 --RAISE WARNING ' AREA: % % %',location.keywords,NEW.country_code,location.country_code;
1408 IF location.rank_search < location_rank_search THEN
1409 location_rank_search := location.rank_search;
1410 location_distance := location.distance * 1.5;
1413 IF location.distance < location_distance THEN
1415 -- Add it to the list of search terms
1416 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1417 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1418 address_havelevel[location.rank_address] := true;
1424 -- try using the isin value to find parent places
1425 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1426 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1428 FOR location IN SELECT place_id,search_name.name_vector,address_rank,
1429 ST_Distance(place_centroid, search_name.centroid) as distance
1431 WHERE search_name.name_vector @> ARRAY[isin_tokens[i]]
1432 AND search_rank < NEW.rank_search
1433 AND (country_code = NEW.country_code OR address_rank < 4)
1434 ORDER BY ST_distance(NEW.geometry, centroid) ASC limit 1
1436 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1437 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.address_rank], location.distance, location.address_rank);
1443 -- if we have a name add this to the name search table
1444 IF NEW.name IS NOT NULL THEN
1445 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, NEW.country_code,
1446 name_vector, nameaddress_vector, place_centroid);
1456 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1461 --IF OLD.rank_search < 26 THEN
1462 --RAISE WARNING 'delete % % % % %',OLD.place_id,OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1465 -- mark everything linked to this place for re-indexing
1466 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1467 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1469 -- do the actual delete
1470 DELETE FROM location_area where place_id = OLD.place_id;
1471 DELETE FROM search_name where place_id = OLD.place_id;
1472 DELETE FROM place_addressline where place_id = OLD.place_id;
1473 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1481 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1487 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1488 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1495 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1500 existingplacex RECORD;
1501 existinggeometry GEOMETRY;
1502 existingplace_id INTEGER;
1506 IF FALSE AND NEW.osm_type = 'R' THEN
1507 RAISE WARNING '-----------------------------------------------------------------------------------';
1508 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1509 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;
1510 RAISE WARNING '%', existingplacex;
1513 -- Just block these - lots and pointless
1514 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1517 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1521 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
1522 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1526 -- Patch in additional country names
1527 -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1528 IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1529 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1532 -- Have we already done this place?
1533 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;
1535 -- Get the existing place_id
1536 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;
1538 -- Handle a place changing type by removing the old data
1539 -- My generated 'place' types are causing havok because they overlap with real tags
1540 -- TODO: move them to their own special purpose tag to avoid collisions
1541 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1542 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');
1545 -- RAISE WARNING 'Existing: %',existing.place_id;
1547 -- 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
1548 IF existing.osm_type IS NULL
1549 OR existingplacex.osm_type IS NULL
1550 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1551 -- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1552 OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1553 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1556 -- IF existing.osm_type IS NULL THEN
1557 -- RAISE WARNING 'no existing place';
1559 -- IF existingplacex.osm_type IS NULL THEN
1560 -- RAISE WARNING 'no existing placex %', existingplacex;
1564 -- RAISE WARNING 'delete and replace';
1566 IF existing.osm_type IS NOT NULL THEN
1567 -- 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;
1568 IF existing.rank_search < 26 THEN
1569 -- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1571 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1574 -- RAISE WARNING 'delete and replace2';
1576 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1577 insert into placex values (NEW.place_id
1589 ,NEW.street_place_id
1596 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1601 -- Various ways to do the update
1603 -- Debug, what's changed?
1604 IF FALSE AND existing.rank_search < 26 THEN
1605 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1606 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1608 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1609 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1611 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1612 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1614 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1615 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1617 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1618 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1620 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1621 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1625 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1626 IF existing.geometry != NEW.geometry
1627 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1628 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1631 -- IF existing.rank_search < 26 THEN
1632 -- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1635 -- Get the version of the geometry actually used (in placex table)
1636 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;
1638 -- Performance limit
1639 IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1641 -- 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
1642 update placex set indexed_status = 2 where indexed_status = 0 and
1643 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1644 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1645 AND rank_search > NEW.rank_search;
1647 update placex set indexed_status = 2 where indexed_status = 0 and
1648 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1649 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1650 AND rank_search > NEW.rank_search;
1656 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1657 IF existingplacex.rank_search < 26
1658 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1659 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1660 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1661 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1662 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1663 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1666 -- IF existing.rank_search < 26 THEN
1667 -- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1670 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1672 IF st_area(NEW.geometry) < 0.5 THEN
1673 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1674 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1681 -- Anything else has changed - reindex the lot
1682 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1683 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1684 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1685 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1686 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1687 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1689 -- IF existing.rank_search < 26 THEN
1690 -- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1693 -- performance, can't take the load of re-indexing a whole country / huge area
1694 IF st_area(NEW.geometry) < 0.5 THEN
1695 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1696 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1703 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1704 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1705 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1706 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1707 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1708 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1709 OR existing.geometry != NEW.geometry
1714 housenumber = NEW.housenumber,
1715 street = NEW.street,
1717 postcode = NEW.postcode,
1718 country_code = NEW.country_code,
1719 street_place_id = null,
1720 geometry = NEW.geometry
1721 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1725 housenumber = NEW.housenumber,
1726 street = NEW.street,
1728 postcode = NEW.postcode,
1729 country_code = NEW.country_code,
1730 street_place_id = null,
1732 geometry = NEW.geometry
1733 where place_id = existingplacex.place_id;
1735 result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1739 -- Abort the add (we modified the existing place instead)
1743 $$ LANGUAGE plpgsql;
1745 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1752 IF name is null THEN
1756 search := languagepref;
1758 FOR j IN 1..array_upper(search, 1) LOOP
1759 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1760 return trim(name->search[j]);
1767 LANGUAGE plpgsql IMMUTABLE;
1769 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1772 searchnodes INTEGER[];
1777 searchnodes := '{}';
1778 FOR j IN 1..array_upper(way_ids, 1) LOOP
1780 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1782 searchnodes := searchnodes | location.nodes;
1786 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1789 LANGUAGE plpgsql IMMUTABLE;
1791 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT
1802 search := ARRAY['ref'];
1805 UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
1807 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1810 select rank_address,name,distance,length(name::text) as namelength
1811 from place_addressline join placex on (address_place_id = placex.place_id)
1812 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1813 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1815 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1816 FOR j IN 1..array_upper(search, 1) LOOP
1817 FOR k IN 1..array_upper(location.name, 1) LOOP
1818 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
1819 result[(100 - location.rank_address)] := trim(location.name[k].value);
1820 found := location.rank_address;
1827 RETURN array_to_string(result,', ');
1832 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT
1839 searchcountrycode varchar(2);
1840 searchhousenumber TEXT;
1841 searchrankaddress INTEGER;
1845 search := languagepref;
1848 select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress;
1851 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1852 CASE WHEN type = 'postcode' THEN 'name' => postcode ELSE name END as name,
1853 distance,length(name::text) as namelength
1854 from place_addressline join placex on (address_place_id = placex.place_id)
1855 where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
1856 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1857 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1859 IF array_upper(search, 1) IS NOT NULL AND location.name IS NOT NULL THEN
1860 FOR j IN 1..array_upper(search, 1) LOOP
1861 IF (found > location.rank_address AND location.name ? search[j] AND location.name -> search[j] != ''
1862 AND NOT result && ARRAY[location.name -> search[j]]) THEN
1863 result[(100 - location.rank_address)] := trim(location.name -> search[j]);
1864 found := location.rank_address;
1870 IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
1871 IF result[(100 - 28)] IS NOT NULL THEN
1872 result[(100 - 29)] := result[(100 - 28)];
1874 result[(100 - 28)] := searchhousenumber;
1877 -- No country polygon - add it from the country_code
1879 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1880 where place_id = for_place_id limit 1 INTO location;
1881 IF location IS NOT NULL THEN
1882 result[(100 - 4)] := trim(location.name);
1886 RETURN array_to_string(result,', ');
1891 CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT[]
1898 searchcountrycode varchar(2);
1899 searchhousenumber TEXT;
1903 search := languagepref;
1906 UPDATE placex set indexed_status = 0 where indexed_status > 0 and place_id = for_place_id;
1908 select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
1911 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1912 name,distance,length(name::text) as namelength
1913 from place_addressline join placex on (address_place_id = placex.place_id)
1914 where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
1915 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1916 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1918 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1919 FOR j IN 1..array_upper(search, 1) LOOP
1920 FOR k IN 1..array_upper(location.name, 1) LOOP
1921 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
1922 result[(100 - location.rank_address)] := trim(location.name[k].value);
1923 found := location.rank_address;
1930 IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
1931 result[(100 - 28)] := searchhousenumber;
1934 -- No country polygon - add it from the country_code
1936 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1937 where place_id = for_place_id limit 1 INTO location;
1938 IF location IS NOT NULL THEN
1939 result[(100 - 4)] := trim(location.name);
1948 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
1951 result place_boundingbox;
1952 numfeatures integer;
1954 select * from place_boundingbox into result where place_id = search_place_id;
1955 IF result.place_id IS NULL THEN
1956 -- remove isaddress = true because if there is a matching polygon it always wins
1957 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
1958 insert into place_boundingbox select place_id,
1959 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
1960 ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
1961 numfeatures, ST_Area(area),
1962 area from location_area where place_id = search_place_id;
1963 select * from place_boundingbox into result where place_id = search_place_id;
1965 IF result.place_id IS NULL THEN
1967 insert into place_boundingbox select address_place_id,
1968 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
1969 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
1970 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
1971 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
1972 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)
1973 where address_place_id = search_place_id
1974 -- and (isaddress = true OR place_id = search_place_id)
1975 and (st_length(geometry) < 0.01 or place_id = search_place_id)
1976 group by address_place_id limit 1;
1977 select * from place_boundingbox into result where place_id = search_place_id;
1984 -- don't do the operation if it would be slow
1985 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
1988 result place_boundingbox;
1989 numfeatures integer;
1992 select * from place_boundingbox into result where place_id = search_place_id;
1993 IF result IS NULL AND rank > 14 THEN
1994 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
1995 insert into place_boundingbox select place_id,
1996 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
1997 ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
1998 numfeatures, ST_Area(area),
1999 area from location_area where place_id = search_place_id;
2000 select * from place_boundingbox into result where place_id = search_place_id;
2002 IF result IS NULL THEN
2003 select rank_search from placex where place_id = search_place_id into rank;
2006 insert into place_boundingbox select address_place_id,
2007 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2008 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2009 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2010 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2011 from place_addressline join placex using (place_id)
2012 where address_place_id = search_place_id
2013 and (isaddress = true OR place_id = search_place_id)
2014 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2015 group by address_place_id limit 1;
2016 select * from place_boundingbox into result where place_id = search_place_id;
2024 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2027 result place_boundingbox;
2028 numfeatures integer;
2032 housenumber = place.housenumber,
2033 street = place.street,
2035 postcode = place.postcode,
2036 country_code = place.country_code,
2037 street_place_id = null,
2040 where placex.place_id = search_place_id
2041 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2042 and place.class = placex.class and place.type = placex.type;
2043 update placex set indexed = true where place_id = search_place_id and indexed = false;
2049 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2052 result place_boundingbox;
2053 numfeatures integer;
2057 housenumber = place.housenumber,
2058 street = place.street,
2060 postcode = place.postcode,
2061 country_code = place.country_code,
2062 street_place_id = null,
2065 where placex.place_id = search_place_id
2066 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2067 and place.class = placex.class and place.type = placex.type;
2068 update placex set indexed = true where place_id = search_place_id and indexed = false;
2074 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2080 ELSEIF rank < 4 THEN
2082 ELSEIF rank < 8 THEN
2084 ELSEIF rank < 12 THEN
2086 ELSEIF rank < 16 THEN
2088 ELSEIF rank = 16 THEN
2090 ELSEIF rank = 17 THEN
2091 RETURN 'Town / Island';
2092 ELSEIF rank = 18 THEN
2093 RETURN 'Village / Hamlet';
2094 ELSEIF rank = 20 THEN
2096 ELSEIF rank = 21 THEN
2097 RETURN 'Postcode Area';
2098 ELSEIF rank = 22 THEN
2099 RETURN 'Croft / Farm / Locality / Islet';
2100 ELSEIF rank = 23 THEN
2101 RETURN 'Postcode Area';
2102 ELSEIF rank = 25 THEN
2103 RETURN 'Postcode Point';
2104 ELSEIF rank = 26 THEN
2105 RETURN 'Street / Major Landmark';
2106 ELSEIF rank = 27 THEN
2107 RETURN 'Minory Street / Path';
2108 ELSEIF rank = 28 THEN
2109 RETURN 'House / Building';
2111 RETURN 'Other: '||rank;
2118 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2124 ELSEIF rank < 2 THEN
2126 ELSEIF rank < 4 THEN
2128 ELSEIF rank = 5 THEN
2130 ELSEIF rank < 8 THEN
2132 ELSEIF rank < 12 THEN
2134 ELSEIF rank < 16 THEN
2136 ELSEIF rank = 16 THEN
2138 ELSEIF rank = 17 THEN
2139 RETURN 'Town / Village / Hamlet';
2140 ELSEIF rank = 20 THEN
2142 ELSEIF rank = 21 THEN
2143 RETURN 'Postcode Area';
2144 ELSEIF rank = 22 THEN
2145 RETURN 'Croft / Farm / Locality / Islet';
2146 ELSEIF rank = 23 THEN
2147 RETURN 'Postcode Area';
2148 ELSEIF rank = 25 THEN
2149 RETURN 'Postcode Point';
2150 ELSEIF rank = 26 THEN
2151 RETURN 'Street / Major Landmark';
2152 ELSEIF rank = 27 THEN
2153 RETURN 'Minory Street / Path';
2154 ELSEIF rank = 28 THEN
2155 RETURN 'House / Building';
2157 RETURN 'Other: '||rank;
2164 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2171 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2172 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2179 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2187 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2189 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2190 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2192 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2200 CREATE AGGREGATE array_agg(INT[])