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 get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS TEXT
528 place_centre GEOMETRY;
531 FOR nearcountry IN select country_code from country_name where country_code = in_country_code
533 RETURN nearcountry.country_code;
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),
554 partition varchar(10),
557 rank_address INTEGER,
577 IF rank_search > 26 THEN
578 RAISE EXCEPTION 'Adding location with rank > 26 (% rank %)', place_id, rank_search;
581 x := deleteLocationArea(partition, place_id);
584 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
587 centroid := ST_Centroid(geometry);
589 xmin := floor(st_xmin(geometry));
590 xmax := ceil(st_xmax(geometry));
591 ymin := floor(st_ymin(geometry));
592 ymax := ceil(st_ymax(geometry));
594 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
595 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
597 FOR lon IN xmin..(xmax-1) LOOP
598 FOR lat IN ymin..(ymax-1) LOOP
599 secgeo := st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326));
600 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
601 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
607 ELSEIF rank_search < 26 THEN
610 IF rank_search = 14 THEN
612 ELSEIF rank_search = 15 THEN
614 ELSEIF rank_search = 16 THEN
616 ELSEIF rank_search = 17 THEN
618 ELSEIF rank_search = 25 THEN
622 secgeo := ST_Buffer(geometry, diameter);
623 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
628 secgeo := ST_Buffer(geometry, 0.0002);
629 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
632 secgeo := ST_Buffer(geometry, 0.001);
633 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
642 CREATE OR REPLACE FUNCTION update_location(
644 place_country_code varchar(2),
647 rank_address INTEGER,
655 b := delete_location(place_id);
656 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
661 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[])
672 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
673 FOR childplace IN select * from search_name,place_addressline
674 where address_place_id = parent_place_id
675 and search_name.place_id = place_addressline.place_id
677 delete from search_name where place_id = childplace.place_id;
678 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
679 IF childplace.place_id = parent_place_id THEN
680 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
682 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
683 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
684 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
692 CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN
695 newkeywords INTEGER[];
696 addedkeywords INTEGER[];
697 removedkeywords INTEGER[];
701 newkeywords := make_keywords(name);
702 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
703 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
704 where place_id = OLD_place_id into addedkeywords, removedkeywords;
706 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
708 IF #removedkeywords > 0 THEN
709 -- abort due to tokens removed
713 IF #addedkeywords > 0 THEN
714 -- short circuit - no changes
718 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
719 RETURN search_name_add_words(OLD_place_id, addedkeywords);
725 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
737 orginalstartnumber INTEGER;
738 originalnumberrange INTEGER;
741 search_place_id INTEGER;
743 havefirstpoint BOOLEAN;
747 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
749 select nodes from planet_osm_ways where id = wayid INTO waynodes;
750 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
751 IF array_upper(waynodes, 1) IS NOT NULL THEN
753 havefirstpoint := false;
755 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
757 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
758 IF search_place_id IS NULL THEN
759 -- null record of right type
760 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
761 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
763 select * from placex where place_id = search_place_id INTO nextnode;
766 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
768 IF havefirstpoint THEN
770 -- add point to the line string
771 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
772 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
774 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
776 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
778 IF startnumber != endnumber THEN
780 linestr := linestr || ')';
781 --RAISE WARNING 'linestr %',linestr;
782 linegeo := ST_GeomFromText(linestr,4326);
783 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
784 IF (startnumber > endnumber) THEN
785 housenum := endnumber;
786 endnumber := startnumber;
787 startnumber := housenum;
788 linegeo := ST_Reverse(linegeo);
790 orginalstartnumber := startnumber;
791 originalnumberrange := endnumber - startnumber;
793 -- Too much broken data worldwide for this test to be worth using
794 -- IF originalnumberrange > 500 THEN
795 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
798 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
799 startnumber := startnumber + 1;
802 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
803 startnumber := startnumber + 2;
805 ELSE -- everything else assumed to be 'all'
806 startnumber := startnumber + 1;
810 endnumber := endnumber - 1;
811 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
812 FOR housenum IN startnumber..endnumber BY stepsize LOOP
813 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
814 -- ideally postcodes should move up to the way
815 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin,
816 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
817 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin,
818 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));
819 newpoints := newpoints + 1;
820 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
823 havefirstpoint := false;
827 IF NOT havefirstpoint THEN
828 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
829 IF startnumber IS NOT NULL AND startnumber > 0 THEN
830 havefirstpoint := true;
831 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
832 prevnode := nextnode;
834 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
840 --RAISE WARNING 'interpolation points % ',newpoints;
847 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
853 country_code VARCHAR(2);
856 -- RAISE WARNING '%',NEW.osm_id;
859 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
862 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
866 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
867 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
871 IF NEW.osm_type = 'R' THEN
872 -- invalid multipolygons can crash postgis, don't even bother to try!
875 NEW.geometry := ST_buffer(NEW.geometry,0);
876 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
877 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
882 NEW.place_id := nextval('seq_place');
883 NEW.indexed_status := 1; --STATUS_NEW
885 IF NEW.country_code is null THEN
886 NEW.country_code := get_country_code(NEW.geometry);
888 NEW.geometry_sector := geometry_sector(NEW.geometry);
889 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
891 IF NEW.admin_level > 15 THEN
892 NEW.admin_level := 15;
895 IF NEW.housenumber IS NOT NULL THEN
896 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
899 IF NEW.osm_type = 'X' THEN
900 -- E'X'ternal records should already be in the right format so do nothing
902 NEW.rank_search := 30;
903 NEW.rank_address := NEW.rank_search;
905 -- By doing in postgres we have the country available to us - currently only used for postcode
906 IF NEW.class = 'place' THEN
907 IF NEW.type in ('continent') THEN
908 NEW.rank_search := 2;
909 NEW.rank_address := NEW.rank_search;
910 ELSEIF NEW.type in ('sea') THEN
911 NEW.rank_search := 2;
912 NEW.rank_address := 0;
913 ELSEIF NEW.type in ('country') THEN
914 NEW.rank_search := 4;
915 NEW.rank_address := NEW.rank_search;
916 ELSEIF NEW.type in ('state') THEN
917 NEW.rank_search := 8;
918 NEW.rank_address := NEW.rank_search;
919 ELSEIF NEW.type in ('region') THEN
920 NEW.rank_search := 10;
921 NEW.rank_address := NEW.rank_search;
922 ELSEIF NEW.type in ('county') THEN
923 NEW.rank_search := 12;
924 NEW.rank_address := NEW.rank_search;
925 ELSEIF NEW.type in ('city') THEN
926 NEW.rank_search := 16;
927 NEW.rank_address := NEW.rank_search;
928 ELSEIF NEW.type in ('island') THEN
929 NEW.rank_search := 17;
930 NEW.rank_address := 0;
931 ELSEIF NEW.type in ('town') THEN
932 NEW.rank_search := 17;
933 NEW.rank_address := NEW.rank_search;
934 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
935 NEW.rank_search := 18;
936 NEW.rank_address := 17;
937 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
938 NEW.rank_search := 18;
939 NEW.rank_address := 17;
940 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
941 NEW.rank_search := 17;
942 NEW.rank_address := 18;
943 ELSEIF NEW.type in ('moor') THEN
944 NEW.rank_search := 17;
945 NEW.rank_address := 0;
946 ELSEIF NEW.type in ('national_park') THEN
947 NEW.rank_search := 18;
948 NEW.rank_address := 18;
949 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
950 NEW.rank_search := 20;
951 NEW.rank_address := NEW.rank_search;
952 ELSEIF NEW.type in ('farm','locality','islet') THEN
953 NEW.rank_search := 20;
954 NEW.rank_address := 0;
955 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
956 NEW.rank_search := 22;
957 NEW.rank_address := 22;
958 ELSEIF NEW.type in ('postcode') THEN
960 NEW.name := 'ref'=>NEW.postcode;
962 IF NEW.country_code = 'gb' THEN
964 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
965 NEW.rank_search := 25;
966 NEW.rank_address := 5;
967 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
968 NEW.rank_search := 23;
969 NEW.rank_address := 5;
970 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
971 NEW.rank_search := 21;
972 NEW.rank_address := 5;
975 ELSEIF NEW.country_code = 'de' THEN
977 IF NEW.postcode ~ '^([0-9]{5})$' THEN
978 NEW.rank_search := 21;
979 NEW.rank_address := 11;
983 -- Guess at the postcode format and coverage (!)
984 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
985 NEW.rank_search := 21;
986 NEW.rank_address := 11;
988 -- Does it look splitable into and area and local code?
989 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
991 IF postcode IS NOT NULL THEN
992 NEW.rank_search := 25;
993 NEW.rank_address := 11;
994 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
995 NEW.rank_search := 21;
996 NEW.rank_address := 11;
1001 ELSEIF NEW.type in ('airport','street') THEN
1002 NEW.rank_search := 26;
1003 NEW.rank_address := NEW.rank_search;
1004 ELSEIF NEW.type in ('house','building') THEN
1005 NEW.rank_search := 30;
1006 NEW.rank_address := NEW.rank_search;
1007 ELSEIF NEW.type in ('houses') THEN
1008 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1009 -- insert new point into place for each derived building
1010 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1011 NEW.rank_search := 28;
1012 NEW.rank_address := 0;
1015 ELSEIF NEW.class = 'boundary' THEN
1016 NEW.rank_search := NEW.admin_level * 2;
1017 NEW.rank_address := NEW.rank_search;
1018 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1019 NEW.rank_search := 22;
1020 NEW.rank_address := NEW.rank_search;
1021 -- any feature more than 5 square miles is probably worth indexing
1022 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1023 NEW.rank_search := 22;
1024 NEW.rank_address := NEW.rank_search;
1025 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1026 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1028 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1030 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1032 ELSEIF NEW.class = 'waterway' THEN
1033 NEW.rank_address := 17;
1034 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
1035 NEW.rank_search := 27;
1036 NEW.rank_address := NEW.rank_search;
1037 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1038 NEW.rank_search := 26;
1039 NEW.rank_address := NEW.rank_search;
1040 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1041 NEW.rank_search := 4;
1042 NEW.rank_address := NEW.rank_search;
1043 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1045 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1046 NEW.rank_search := 18;
1047 NEW.rank_address := 0;
1052 IF NEW.rank_search > 30 THEN
1053 NEW.rank_search := 30;
1056 IF NEW.rank_address > 30 THEN
1057 NEW.rank_address := 30;
1060 -- Block import below rank 22
1061 -- IF NEW.rank_search > 22 THEN
1066 -- The following is not needed until doing diff updates, and slows the main index process down
1068 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1069 -- Performance: We just can't handle re-indexing for country level changes
1070 IF st_area(NEW.geometry) < 1 THEN
1071 -- mark items within the geometry for re-indexing
1072 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1073 -- work around bug in postgis
1074 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1075 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1076 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1077 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1080 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1082 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1083 IF NEW.type='postcode' THEN
1085 ELSEIF NEW.rank_search < 16 THEN
1087 ELSEIF NEW.rank_search < 18 THEN
1089 ELSEIF NEW.rank_search < 20 THEN
1091 ELSEIF NEW.rank_search = 21 THEN
1093 ELSEIF NEW.rank_search < 24 THEN
1095 ELSEIF NEW.rank_search < 26 THEN
1096 diameter := 0.002; -- 100 to 200 meters
1097 ELSEIF NEW.rank_search < 28 THEN
1098 diameter := 0.001; -- 50 to 100 meters
1100 IF diameter > 0 THEN
1101 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1102 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1107 -- IF NEW.rank_search < 26 THEN
1108 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1117 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1122 place_centroid GEOMETRY;
1124 search_maxdistance FLOAT[];
1125 search_mindistance FLOAT[];
1126 address_havelevel BOOLEAN[];
1127 -- search_scores wordscore[];
1128 -- search_scores_pos INTEGER;
1134 search_diameter FLOAT;
1135 search_prevdiameter FLOAT;
1136 search_maxrank INTEGER;
1137 address_maxrank INTEGER;
1138 address_street_word_id INTEGER;
1139 parent_place_id_count INTEGER;
1143 location_rank_search INTEGER;
1144 location_distance FLOAT;
1148 name_vector INTEGER[];
1149 nameaddress_vector INTEGER[];
1154 --RAISE WARNING '%',NEW.place_id;
1155 --RAISE WARNING '%', NEW;
1157 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1158 -- Silently do nothing
1162 IF NEW.country_code is null THEN
1163 NEW.country_code := get_country_code(NEW.geometry);
1165 NEW.country_code := lower(NEW.country_code);
1166 NEW.partition := NEW.country_code;
1167 IF NEW.partition is null THEN
1168 NEW.partition := 'none';
1171 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1173 NEW.indexed_date = now();
1175 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1176 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1180 DELETE FROM search_name WHERE place_id = NEW.place_id;
1181 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1182 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1184 -- Adding ourselves to the list simplifies address calculations later
1185 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1187 -- What level are we searching from
1188 search_maxrank := NEW.rank_search;
1190 -- Speed up searches - just use the centroid of the feature
1191 -- cheaper but less acurate
1192 place_centroid := ST_Centroid(NEW.geometry);
1194 -- Initialise the name vector using our name
1195 name_vector := make_keywords(NEW.name);
1196 nameaddress_vector := '{}'::int[];
1198 -- some tag combinations add a special id for search
1199 tagpairid := get_tagpair(NEW.class,NEW.type);
1200 IF tagpairid IS NOT NULL THEN
1201 name_vector := name_vector + tagpairid;
1204 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1206 -- For low level elements we inherit from our parent road
1207 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1209 --RAISE WARNING 'finding street for %', NEW;
1211 NEW.parent_place_id := null;
1213 -- to do that we have to find our parent road
1214 -- Copy data from linked items (points on ways, addr:street links, relations)
1215 -- Note that addr:street links can only be indexed once the street itself is indexed
1216 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1218 -- Is this node part of a relation?
1219 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1221 -- At the moment we only process one type of relation - associatedStreet
1222 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1223 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1224 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1225 --RAISE WARNING 'node in relation %',relation;
1226 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1227 and rank_search = 26 INTO NEW.parent_place_id;
1233 --RAISE WARNING 'x1';
1234 -- Is this node part of a way?
1235 FOR location IN select * from placex where osm_type = 'W'
1236 and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer])
1238 --RAISE WARNING '%', location;
1239 -- Way IS a road then we are on it - that must be our road
1240 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1241 --RAISE WARNING 'node in way that is a street %',location;
1242 NEW.parent_place_id := location.place_id;
1245 -- Is the WAY part of a relation
1246 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1248 -- At the moment we only process one type of relation - associatedStreet
1249 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1250 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1251 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1252 --RAISE WARNING 'node in way that is in a relation %',relation;
1253 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1254 and rank_search = 26 INTO NEW.parent_place_id;
1260 -- If the way contains an explicit name of a street copy it
1261 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1262 --RAISE WARNING 'node in way that has a streetname %',location;
1263 NEW.street := location.street;
1266 -- If this way is a street interpolation line then it is probably as good as we are going to get
1267 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1268 -- Try and find a way that is close roughly parellel to this line
1269 FOR relation IN SELECT place_id FROM placex
1270 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1271 and st_geometrytype(location.geometry) in ('ST_LineString')
1272 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1273 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1274 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1276 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1277 NEW.parent_place_id := relation.place_id;
1285 --RAISE WARNING 'x2';
1287 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1288 -- Is this way part of a relation?
1289 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1291 -- At the moment we only process one type of relation - associatedStreet
1292 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1293 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1294 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1295 --RAISE WARNING 'way that is in a relation %',relation;
1296 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1297 and rank_search = 26 INTO NEW.parent_place_id;
1304 --RAISE WARNING 'x3';
1306 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1307 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1308 --RAISE WARNING 'street: % %', NEW.street, address_street_word_id;
1309 IF address_street_word_id IS NOT NULL THEN
1310 FOR location IN SELECT place_id,ST_distance(NEW.geometry, search_name.centroid) as distance
1311 FROM search_name WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1312 AND ST_DWithin(NEW.geometry, search_name.centroid, 0.01) and search_rank between 22 and 27
1313 ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1315 --RAISE WARNING 'streetname found nearby %',location;
1316 NEW.parent_place_id := location.place_id;
1319 -- Failed, fall back to nearest - don't just stop
1320 IF NEW.parent_place_id IS NULL THEN
1321 --RAISE WARNING 'unable to find streetname nearby % %',NEW.street,address_street_word_id;
1326 --RAISE WARNING 'x4';
1328 IF NEW.parent_place_id IS NULL THEN
1329 FOR location IN SELECT place_id FROM getNearRoads(NEW.partition, place_centroid) LOOP
1330 NEW.parent_place_id := location.place_id;
1334 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1336 -- If we didn't find any road fallback to standard method
1337 IF NEW.parent_place_id IS NOT NULL THEN
1339 -- Some unnamed roads won't have been indexed, index now if needed
1340 -- ALL are now indexed!
1341 -- select count(*) from place_addressline where place_id = NEW.parent_place_id INTO parent_place_id_count;
1342 -- IF parent_place_id_count = 0 THEN
1343 -- UPDATE placex set indexed = true where indexed = false and place_id = NEW.parent_place_id;
1346 -- Add the street to the address as zero distance to force to front of list
1347 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1348 address_havelevel[26] := true;
1350 -- Import address details from parent, reclculating distance in process
1351 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
1352 from place_addressline as x join placex on (address_place_id = placex.place_id)
1353 where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1355 -- Get the details of the parent road
1356 select * from search_name where place_id = NEW.parent_place_id INTO location;
1357 NEW.country_code := location.country_code;
1359 --RAISE WARNING '%', NEW.name;
1360 -- If there is no name it isn't searchable, don't bother to create a search record
1361 IF NEW.name is NULL THEN
1365 -- Merge address from parent
1366 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1368 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1369 -- Just be happy with inheriting from parent road only
1370 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, 0, NEW.country_code,
1371 name_vector, nameaddress_vector, place_centroid);
1378 --RAISE WARNING ' INDEXING: %',NEW;
1380 -- convert isin to array of tokenids
1381 isin_tokens := '{}'::int[];
1382 IF NEW.isin IS NOT NULL THEN
1383 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1384 IF array_upper(isin, 1) IS NOT NULL THEN
1385 FOR i IN 1..array_upper(isin, 1) LOOP
1386 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1387 IF address_street_word_id IS NOT NULL THEN
1388 isin_tokens := isin_tokens + address_street_word_id;
1392 isin_tokens := uniq(sort(isin_tokens));
1395 -- Process area matches
1396 location_rank_search := 100;
1397 location_distance := 0;
1398 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1400 --RAISE WARNING ' AREA: %',location;
1402 IF location.rank_search < location_rank_search THEN
1403 location_rank_search := location.rank_search;
1404 location_distance := location.distance * 1.5;
1407 IF location.distance < location_distance THEN
1409 -- Add it to the list of search terms
1410 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1411 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1412 address_havelevel[location.rank_address] := true;
1418 -- try using the isin value to find parent places
1419 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1420 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1422 FOR location IN SELECT place_id,search_name.name_vector,address_rank,
1423 ST_Distance(place_centroid, search_name.centroid) as distance
1425 WHERE search_name.name_vector @> ARRAY[isin_tokens[i]]
1426 AND search_rank < NEW.rank_search
1427 AND (country_code = NEW.country_code OR address_rank < 4)
1428 ORDER BY ST_distance(NEW.geometry, centroid) ASC limit 1
1430 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1431 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.address_rank], location.distance, location.address_rank);
1437 -- if we have a name add this to the name search table
1438 IF NEW.name IS NOT NULL THEN
1440 IF NEW.rank_search <= 26 THEN
1441 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1444 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code,
1445 name_vector, nameaddress_vector, place_centroid);
1455 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1460 --IF OLD.rank_search < 26 THEN
1461 --RAISE WARNING 'delete % % % % %',OLD.place_id,OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1464 -- mark everything linked to this place for re-indexing
1465 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1466 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1468 -- do the actual delete
1469 DELETE FROM location_area where place_id = OLD.place_id;
1470 DELETE FROM search_name where place_id = OLD.place_id;
1471 DELETE FROM place_addressline where place_id = OLD.place_id;
1472 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1480 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1486 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1487 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1494 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1499 existingplacex RECORD;
1500 existinggeometry GEOMETRY;
1501 existingplace_id INTEGER;
1505 IF FALSE AND NEW.osm_type = 'R' THEN
1506 RAISE WARNING '-----------------------------------------------------------------------------------';
1507 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1508 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;
1509 RAISE WARNING '%', existingplacex;
1512 -- Just block these - lots and pointless
1513 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1516 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1520 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
1521 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1525 -- Patch in additional country names
1526 -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1527 IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1528 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1531 -- Have we already done this place?
1532 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;
1534 -- Get the existing place_id
1535 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;
1537 -- Handle a place changing type by removing the old data
1538 -- My generated 'place' types are causing havok because they overlap with real tags
1539 -- TODO: move them to their own special purpose tag to avoid collisions
1540 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1541 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');
1544 -- RAISE WARNING 'Existing: %',existing.place_id;
1546 -- 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
1547 IF existing.osm_type IS NULL
1548 OR existingplacex.osm_type IS NULL
1549 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1550 -- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1551 OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1552 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1555 -- IF existing.osm_type IS NULL THEN
1556 -- RAISE WARNING 'no existing place';
1558 -- IF existingplacex.osm_type IS NULL THEN
1559 -- RAISE WARNING 'no existing placex %', existingplacex;
1563 -- RAISE WARNING 'delete and replace';
1565 IF existing.osm_type IS NOT NULL THEN
1566 -- 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;
1567 IF existing.rank_search < 26 THEN
1568 -- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1570 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1573 -- RAISE WARNING 'delete and replace2';
1575 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1576 insert into placex values (NEW.place_id
1588 ,NEW.parent_place_id
1595 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1600 -- Various ways to do the update
1602 -- Debug, what's changed?
1603 IF FALSE AND existing.rank_search < 26 THEN
1604 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1605 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1607 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1608 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1610 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1611 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1613 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1614 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1616 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1617 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1619 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1620 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1624 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1625 IF existing.geometry != NEW.geometry
1626 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1627 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1630 -- IF existing.rank_search < 26 THEN
1631 -- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1634 -- Get the version of the geometry actually used (in placex table)
1635 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;
1637 -- Performance limit
1638 IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1640 -- 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
1641 update placex set indexed_status = 2 where indexed_status = 0 and
1642 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1643 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1644 AND rank_search > NEW.rank_search;
1646 update placex set indexed_status = 2 where indexed_status = 0 and
1647 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1648 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1649 AND rank_search > NEW.rank_search;
1655 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1656 IF existingplacex.rank_search < 26
1657 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1658 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1659 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1660 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1661 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1662 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1665 -- IF existing.rank_search < 26 THEN
1666 -- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1669 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1671 IF st_area(NEW.geometry) < 0.5 THEN
1672 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1673 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1680 -- Anything else has changed - reindex the lot
1681 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1682 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1683 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1684 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1685 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1686 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1688 -- IF existing.rank_search < 26 THEN
1689 -- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1692 -- performance, can't take the load of re-indexing a whole country / huge area
1693 IF st_area(NEW.geometry) < 0.5 THEN
1694 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1695 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1702 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1703 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1704 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1705 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1706 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1707 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1708 OR existing.geometry != NEW.geometry
1713 housenumber = NEW.housenumber,
1714 street = NEW.street,
1716 postcode = NEW.postcode,
1717 country_code = NEW.country_code,
1718 parent_place_id = null,
1719 geometry = NEW.geometry
1720 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1724 housenumber = NEW.housenumber,
1725 street = NEW.street,
1727 postcode = NEW.postcode,
1728 country_code = NEW.country_code,
1729 parent_place_id = null,
1731 geometry = NEW.geometry
1732 where place_id = existingplacex.place_id;
1734 result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1738 -- Abort the add (we modified the existing place instead)
1742 $$ LANGUAGE plpgsql;
1744 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1751 IF name is null THEN
1755 search := languagepref;
1757 FOR j IN 1..array_upper(search, 1) LOOP
1758 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1759 return trim(name->search[j]);
1766 LANGUAGE plpgsql IMMUTABLE;
1768 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1771 searchnodes INTEGER[];
1776 searchnodes := '{}';
1777 FOR j IN 1..array_upper(way_ids, 1) LOOP
1779 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1781 searchnodes := searchnodes | location.nodes;
1785 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1788 LANGUAGE plpgsql IMMUTABLE;
1790 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT
1801 search := ARRAY['ref'];
1804 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1807 select rank_address,name,distance,length(name::text) as namelength
1808 from place_addressline join placex on (address_place_id = placex.place_id)
1809 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1810 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1812 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1813 FOR j IN 1..array_upper(search, 1) LOOP
1814 FOR k IN 1..array_upper(location.name, 1) LOOP
1815 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
1816 result[(100 - location.rank_address)] := trim(location.name[k].value);
1817 found := location.rank_address;
1824 RETURN array_to_string(result,', ');
1829 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT
1836 searchcountrycode varchar(2);
1837 searchhousenumber TEXT;
1838 searchrankaddress INTEGER;
1842 search := languagepref;
1845 select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress;
1848 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1849 CASE WHEN type = 'postcode' THEN 'name' => postcode ELSE name END as name,
1850 distance,length(name::text) as namelength
1851 from place_addressline join placex on (address_place_id = placex.place_id)
1852 where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
1853 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1854 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1856 IF array_upper(search, 1) IS NOT NULL AND location.name IS NOT NULL THEN
1857 FOR j IN 1..array_upper(search, 1) LOOP
1858 IF (found > location.rank_address AND location.name ? search[j] AND location.name -> search[j] != ''
1859 AND NOT result && ARRAY[location.name -> search[j]]) THEN
1860 result[(100 - location.rank_address)] := trim(location.name -> search[j]);
1861 found := location.rank_address;
1867 IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
1868 IF result[(100 - 28)] IS NOT NULL THEN
1869 result[(100 - 29)] := result[(100 - 28)];
1871 result[(100 - 28)] := searchhousenumber;
1874 -- No country polygon - add it from the country_code
1876 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1877 where place_id = for_place_id limit 1 INTO location;
1878 IF location IS NOT NULL THEN
1879 result[(100 - 4)] := trim(location.name);
1883 RETURN array_to_string(result,', ');
1888 CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT[]
1895 searchcountrycode varchar(2);
1896 searchhousenumber TEXT;
1900 search := languagepref;
1903 UPDATE placex set indexed_status = 0 where indexed_status > 0 and place_id = for_place_id;
1905 select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
1908 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1909 name,distance,length(name::text) as namelength
1910 from place_addressline join placex on (address_place_id = placex.place_id)
1911 where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
1912 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1913 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1915 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1916 FOR j IN 1..array_upper(search, 1) LOOP
1917 FOR k IN 1..array_upper(location.name, 1) LOOP
1918 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
1919 result[(100 - location.rank_address)] := trim(location.name[k].value);
1920 found := location.rank_address;
1927 IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
1928 result[(100 - 28)] := searchhousenumber;
1931 -- No country polygon - add it from the country_code
1933 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1934 where place_id = for_place_id limit 1 INTO location;
1935 IF location IS NOT NULL THEN
1936 result[(100 - 4)] := trim(location.name);
1945 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
1948 result place_boundingbox;
1949 numfeatures integer;
1951 select * from place_boundingbox into result where place_id = search_place_id;
1952 IF result.place_id IS NULL THEN
1953 -- remove isaddress = true because if there is a matching polygon it always wins
1954 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
1955 insert into place_boundingbox select place_id,
1956 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
1957 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
1958 numfeatures, ST_Area(geometry),
1959 geometry as area from location_area where place_id = search_place_id;
1960 select * from place_boundingbox into result where place_id = search_place_id;
1962 IF result.place_id IS NULL THEN
1964 insert into place_boundingbox select address_place_id,
1965 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
1966 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
1967 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
1968 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
1969 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)
1970 where address_place_id = search_place_id
1971 -- and (isaddress = true OR place_id = search_place_id)
1972 and (st_length(geometry) < 0.01 or place_id = search_place_id)
1973 group by address_place_id limit 1;
1974 select * from place_boundingbox into result where place_id = search_place_id;
1981 -- don't do the operation if it would be slow
1982 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
1985 result place_boundingbox;
1986 numfeatures integer;
1989 select * from place_boundingbox into result where place_id = search_place_id;
1990 IF result IS NULL AND rank > 14 THEN
1991 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
1992 insert into place_boundingbox select place_id,
1993 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
1994 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
1995 numfeatures, ST_Area(geometry),
1996 geometry as area from location_area where place_id = search_place_id;
1997 select * from place_boundingbox into result where place_id = search_place_id;
1999 IF result IS NULL THEN
2000 select rank_search from placex where place_id = search_place_id into rank;
2003 insert into place_boundingbox select address_place_id,
2004 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2005 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2006 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2007 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2008 from place_addressline join placex using (place_id)
2009 where address_place_id = search_place_id
2010 and (isaddress = true OR place_id = search_place_id)
2011 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2012 group by address_place_id limit 1;
2013 select * from place_boundingbox into result where place_id = search_place_id;
2021 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2024 result place_boundingbox;
2025 numfeatures integer;
2029 housenumber = place.housenumber,
2030 street = place.street,
2032 postcode = place.postcode,
2033 country_code = place.country_code,
2034 parent_place_id = null,
2037 where placex.place_id = search_place_id
2038 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2039 and place.class = placex.class and place.type = placex.type;
2040 update placex set indexed_status = 0 where place_id = search_place_id;
2046 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2049 result place_boundingbox;
2050 numfeatures integer;
2054 housenumber = place.housenumber,
2055 street = place.street,
2057 postcode = place.postcode,
2058 country_code = place.country_code,
2059 parent_place_id = null,
2062 where placex.place_id = search_place_id
2063 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2064 and place.class = placex.class and place.type = placex.type;
2065 update placex set indexed_status = 0 where place_id = search_place_id;
2071 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2077 ELSEIF rank < 4 THEN
2079 ELSEIF rank < 8 THEN
2081 ELSEIF rank < 12 THEN
2083 ELSEIF rank < 16 THEN
2085 ELSEIF rank = 16 THEN
2087 ELSEIF rank = 17 THEN
2088 RETURN 'Town / Island';
2089 ELSEIF rank = 18 THEN
2090 RETURN 'Village / Hamlet';
2091 ELSEIF rank = 20 THEN
2093 ELSEIF rank = 21 THEN
2094 RETURN 'Postcode Area';
2095 ELSEIF rank = 22 THEN
2096 RETURN 'Croft / Farm / Locality / Islet';
2097 ELSEIF rank = 23 THEN
2098 RETURN 'Postcode Area';
2099 ELSEIF rank = 25 THEN
2100 RETURN 'Postcode Point';
2101 ELSEIF rank = 26 THEN
2102 RETURN 'Street / Major Landmark';
2103 ELSEIF rank = 27 THEN
2104 RETURN 'Minory Street / Path';
2105 ELSEIF rank = 28 THEN
2106 RETURN 'House / Building';
2108 RETURN 'Other: '||rank;
2115 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2121 ELSEIF rank < 2 THEN
2123 ELSEIF rank < 4 THEN
2125 ELSEIF rank = 5 THEN
2127 ELSEIF rank < 8 THEN
2129 ELSEIF rank < 12 THEN
2131 ELSEIF rank < 16 THEN
2133 ELSEIF rank = 16 THEN
2135 ELSEIF rank = 17 THEN
2136 RETURN 'Town / Village / Hamlet';
2137 ELSEIF rank = 20 THEN
2139 ELSEIF rank = 21 THEN
2140 RETURN 'Postcode Area';
2141 ELSEIF rank = 22 THEN
2142 RETURN 'Croft / Farm / Locality / Islet';
2143 ELSEIF rank = 23 THEN
2144 RETURN 'Postcode Area';
2145 ELSEIF rank = 25 THEN
2146 RETURN 'Postcode Point';
2147 ELSEIF rank = 26 THEN
2148 RETURN 'Street / Major Landmark';
2149 ELSEIF rank = 27 THEN
2150 RETURN 'Minory Street / Path';
2151 ELSEIF rank = 28 THEN
2152 RETURN 'House / Building';
2154 RETURN 'Other: '||rank;
2161 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2168 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2169 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2176 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2184 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2186 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2187 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2189 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2197 CREATE AGGREGATE array_agg(INT[])