1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
56 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
57 NEWgeometry := ST_buffer(NEWgeometry,0);
58 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
62 RETURN (partition*1000000) + (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
72 -- RAISE WARNING '%',osmid;
77 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
78 NEWgeometry := ST_buffer(NEWgeometry,0);
79 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
83 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
86 LANGUAGE plpgsql IMMUTABLE;
88 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
89 AS '{modulepath}/nominatim.so', 'transliteration'
90 LANGUAGE c IMMUTABLE STRICT;
92 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
93 AS '{modulepath}/nominatim.so', 'gettokenstring'
94 LANGUAGE c IMMUTABLE STRICT;
96 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
101 o := gettokenstring(transliteration(name));
102 RETURN trim(substr(o,1,length(o)));
105 LANGUAGE 'plpgsql' IMMUTABLE;
107 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
112 return_word_id INTEGER;
114 lookup_token := trim(lookup_word);
115 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
116 IF return_word_id IS NULL THEN
117 return_word_id := nextval('seq_word');
118 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
120 RETURN return_word_id;
125 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
130 return_word_id INTEGER;
132 lookup_token := ' '||trim(lookup_word);
133 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
134 IF return_word_id IS NULL THEN
135 return_word_id := nextval('seq_word');
136 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
138 RETURN return_word_id;
143 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
148 return_word_id INTEGER;
150 lookup_token := ' '||trim(lookup_word);
151 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
152 IF return_word_id IS NULL THEN
153 return_word_id := nextval('seq_word');
154 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
156 RETURN return_word_id;
161 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
174 RETURN return_word_id;
179 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
184 return_word_id INTEGER;
186 lookup_token := lookup_class||'='||lookup_type;
187 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
188 IF return_word_id IS NULL THEN
189 return_word_id := nextval('seq_word');
190 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
192 RETURN return_word_id;
197 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
202 return_word_id INTEGER;
204 lookup_token := lookup_class||'='||lookup_type;
205 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
206 RETURN return_word_id;
211 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
216 return_word_id INTEGER;
218 lookup_token := ' '||trim(lookup_word);
219 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
220 IF return_word_id IS NULL THEN
221 return_word_id := nextval('seq_word');
222 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null, op);
224 RETURN return_word_id;
229 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
234 nospace_lookup_token TEXT;
235 return_word_id INTEGER;
237 lookup_token := ' '||trim(lookup_word);
238 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
239 IF return_word_id IS NULL THEN
240 return_word_id := nextval('seq_word');
241 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
242 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
243 -- IF ' '||nospace_lookup_token != lookup_token THEN
244 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
247 RETURN return_word_id;
252 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
257 RETURN getorcreate_name_id(lookup_word, '');
262 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
267 return_word_id INTEGER;
269 lookup_token := trim(lookup_word);
270 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
271 RETURN return_word_id;
274 LANGUAGE plpgsql IMMUTABLE;
276 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
281 return_word_id INTEGER;
283 lookup_token := ' '||trim(lookup_word);
284 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
285 RETURN return_word_id;
288 LANGUAGE plpgsql IMMUTABLE;
290 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
297 IF array_upper(a, 1) IS NULL THEN
300 IF array_upper(b, 1) IS NULL THEN
304 FOR i IN 1..array_upper(b, 1) LOOP
305 IF NOT (ARRAY[b[i]] && r) THEN
312 LANGUAGE plpgsql IMMUTABLE;
314 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
324 result := '{}'::INTEGER[];
326 FOR item IN SELECT (each(src)).* LOOP
328 s := make_standard_name(item.value);
330 w := getorcreate_name_id(s, item.value);
331 result := result | w;
333 words := string_to_array(s, ' ');
334 IF array_upper(words, 1) IS NOT NULL THEN
335 FOR j IN 1..array_upper(words, 1) LOOP
336 IF (words[j] != '') THEN
337 w = getorcreate_word_id(words[j]);
338 IF NOT (ARRAY[w] && result) THEN
339 result := result | w;
345 words := regexp_split_to_array(item.value, E'[,;()]');
346 IF array_upper(words, 1) != 1 THEN
347 FOR j IN 1..array_upper(words, 1) LOOP
348 s := make_standard_name(words[j]);
350 w := getorcreate_word_id(s);
351 IF NOT (ARRAY[w] && result) THEN
352 result := result | w;
358 s := regexp_replace(item.value, '市$', '');
359 IF s != item.value THEN
360 s := make_standard_name(s);
362 w := getorcreate_name_id(s, item.value);
363 IF NOT (ARRAY[w] && result) THEN
364 result := result | w;
374 LANGUAGE plpgsql IMMUTABLE;
376 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
386 result := '{}'::INTEGER[];
388 s := make_standard_name(src);
389 w := getorcreate_name_id(s);
391 IF NOT (ARRAY[w] && result) THEN
392 result := result || w;
395 words := string_to_array(s, ' ');
396 IF array_upper(words, 1) IS NOT NULL THEN
397 FOR j IN 1..array_upper(words, 1) LOOP
398 IF (words[j] != '') THEN
399 w = getorcreate_word_id(words[j]);
400 IF NOT (ARRAY[w] && result) THEN
401 result := result || w;
410 LANGUAGE plpgsql IMMUTABLE;
412 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
419 IF (wordscores is null OR words is null) THEN
424 FOR idxword in 1 .. array_upper(words, 1) LOOP
425 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
426 IF wordscores[idxscores].word = words[idxword] THEN
427 result := result + wordscores[idxscores].score;
435 LANGUAGE plpgsql IMMUTABLE;
437 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
440 place_centre GEOMETRY;
443 place_centre := ST_Centroid(place);
445 --RAISE WARNING 'start: %', ST_AsText(place_centre);
447 -- Try for a OSM polygon first
448 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_contains(geometry, place_centre) limit 1
450 RETURN nearcountry.country_code;
453 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
455 -- Try for OSM fallback data
456 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
458 RETURN nearcountry.country_code;
461 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
463 -- Natural earth data (first fallback)
464 FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
466 RETURN nearcountry.country_code;
469 -- Natural earth data (first fallback)
470 FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1
472 RETURN nearcountry.country_code;
475 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
477 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
478 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
480 RETURN nearcountry.country_code;
483 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
485 -- Still not in a country - try nearest within ~12 miles of a country
486 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
487 order by st_distance(geometry, place) limit 1
489 RETURN nearcountry.country_code;
495 LANGUAGE plpgsql IMMUTABLE;
497 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
502 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
504 RETURN nearcountry.country_code;
506 RETURN get_country_code(place);
509 LANGUAGE plpgsql IMMUTABLE;
511 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
516 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
518 RETURN lower(nearcountry.country_default_language_code);
523 LANGUAGE plpgsql IMMUTABLE;
525 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
528 place_centre GEOMETRY;
531 FOR nearcountry IN select partition from country_name where country_code = in_country_code
533 RETURN nearcountry.partition;
538 LANGUAGE plpgsql IMMUTABLE;
540 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id INTEGER) RETURNS BOOLEAN
544 DELETE FROM location_area where place_id = OLD_place_id;
545 -- TODO:location_area
551 CREATE OR REPLACE FUNCTION add_location(
553 country_code varchar(2),
557 rank_address INTEGER,
578 IF rank_search > 25 THEN
579 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
582 RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
584 x := deleteLocationArea(partition, place_id);
587 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
590 centroid := ST_Centroid(geometry);
592 xmin := floor(st_xmin(geometry));
593 xmax := ceil(st_xmax(geometry));
594 ymin := floor(st_ymin(geometry));
595 ymax := ceil(st_ymax(geometry));
597 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
598 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
600 FOR lon IN xmin..(xmax-1) LOOP
601 FOR lat IN ymin..(ymax-1) LOOP
602 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
603 IF st_intersects(geometry, secbox) THEN
604 secgeo := st_intersection(geometry, secbox);
605 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
606 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
613 ELSEIF rank_search < 26 THEN
616 IF rank_address = 0 THEN
618 ELSEIF rank_search <= 14 THEN
620 ELSEIF rank_search <= 15 THEN
622 ELSEIF rank_search <= 16 THEN
624 ELSEIF rank_search <= 17 THEN
626 ELSEIF rank_search <= 21 THEN
628 ELSEIF rank_search = 25 THEN
632 RAISE WARNING 'adding % diameter %', place_id, diameter;
634 secgeo := ST_Buffer(geometry, diameter);
635 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
640 secgeo := ST_Buffer(geometry, 0.0002);
641 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
644 secgeo := ST_Buffer(geometry, 0.001);
645 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
654 CREATE OR REPLACE FUNCTION update_location(
657 place_country_code varchar(2),
660 rank_address INTEGER,
668 b := deleteLocationArea(partition, place_id);
669 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
674 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[])
685 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
686 FOR childplace IN select * from search_name,place_addressline
687 where address_place_id = parent_place_id
688 and search_name.place_id = place_addressline.place_id
690 delete from search_name where place_id = childplace.place_id;
691 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
692 IF childplace.place_id = parent_place_id THEN
693 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
695 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
696 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
697 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
705 CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN
708 newkeywords INTEGER[];
709 addedkeywords INTEGER[];
710 removedkeywords INTEGER[];
714 newkeywords := make_keywords(name);
715 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
716 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
717 where place_id = OLD_place_id into addedkeywords, removedkeywords;
719 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
721 IF #removedkeywords > 0 THEN
722 -- abort due to tokens removed
726 IF #addedkeywords > 0 THEN
727 -- short circuit - no changes
731 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
732 RETURN search_name_add_words(OLD_place_id, addedkeywords);
738 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
750 orginalstartnumber INTEGER;
751 originalnumberrange INTEGER;
754 search_place_id INTEGER;
757 havefirstpoint BOOLEAN;
761 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
763 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
764 select nodes from planet_osm_ways where id = wayid INTO waynodes;
765 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
766 IF array_upper(waynodes, 1) IS NOT NULL THEN
768 havefirstpoint := false;
770 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
772 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
773 IF search_place_id IS NULL THEN
774 -- null record of right type
775 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
776 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
778 select * from placex where place_id = search_place_id INTO nextnode;
781 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
783 IF havefirstpoint THEN
785 -- add point to the line string
786 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
787 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
789 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
791 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
793 IF startnumber != endnumber THEN
795 linestr := linestr || ')';
796 --RAISE WARNING 'linestr %',linestr;
797 linegeo := ST_GeomFromText(linestr,4326);
798 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
799 IF (startnumber > endnumber) THEN
800 housenum := endnumber;
801 endnumber := startnumber;
802 startnumber := housenum;
803 linegeo := ST_Reverse(linegeo);
805 orginalstartnumber := startnumber;
806 originalnumberrange := endnumber - startnumber;
808 -- Too much broken data worldwide for this test to be worth using
809 -- IF originalnumberrange > 500 THEN
810 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
813 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
814 startnumber := startnumber + 1;
817 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
818 startnumber := startnumber + 2;
820 ELSE -- everything else assumed to be 'all'
821 startnumber := startnumber + 1;
825 endnumber := endnumber - 1;
826 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
827 FOR housenum IN startnumber..endnumber BY stepsize LOOP
828 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
829 -- ideally postcodes should move up to the way
830 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
831 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
832 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
833 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));
834 newpoints := newpoints + 1;
835 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
838 havefirstpoint := false;
842 IF NOT havefirstpoint THEN
843 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
844 IF startnumber IS NOT NULL AND startnumber > 0 THEN
845 havefirstpoint := true;
846 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
847 prevnode := nextnode;
849 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
855 --RAISE WARNING 'interpolation points % ',newpoints;
862 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
868 country_code VARCHAR(2);
869 default_language VARCHAR(10);
872 -- RAISE WARNING '%',NEW.osm_id;
875 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
878 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
882 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
883 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
887 IF NEW.osm_type = 'R' THEN
888 -- invalid multipolygons can crash postgis, don't even bother to try!
891 NEW.geometry := ST_buffer(NEW.geometry,0);
892 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
893 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
898 NEW.place_id := nextval('seq_place');
899 NEW.indexed_status := 1; --STATUS_NEW
901 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
902 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
903 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
905 -- copy 'name' to or from the default language (if there is a default language)
906 IF NEW.name is not null AND array_upper(%#NEW.name,1) > 1 THEN
907 default_language := get_country_language_code(NEW.country_code);
908 IF default_language IS NOT NULL THEN
909 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
910 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
911 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
912 NEW.name := NEW.name || ('name' => (NEW.name -> 'name:'||default_language));
917 IF NEW.admin_level > 15 THEN
918 NEW.admin_level := 15;
921 IF NEW.housenumber IS NOT NULL THEN
922 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
925 IF NEW.osm_type = 'X' THEN
926 -- E'X'ternal records should already be in the right format so do nothing
928 NEW.rank_search := 30;
929 NEW.rank_address := NEW.rank_search;
931 -- By doing in postgres we have the country available to us - currently only used for postcode
932 IF NEW.class = 'place' THEN
933 IF NEW.type in ('continent') THEN
934 NEW.rank_search := 2;
935 NEW.rank_address := NEW.rank_search;
936 ELSEIF NEW.type in ('sea') THEN
937 NEW.rank_search := 2;
938 NEW.rank_address := 0;
939 ELSEIF NEW.type in ('country') THEN
940 NEW.rank_search := 4;
941 NEW.rank_address := NEW.rank_search;
942 ELSEIF NEW.type in ('state') THEN
943 NEW.rank_search := 8;
944 NEW.rank_address := NEW.rank_search;
945 ELSEIF NEW.type in ('region') THEN
946 NEW.rank_search := 10;
947 NEW.rank_address := NEW.rank_search;
948 ELSEIF NEW.type in ('county') THEN
949 NEW.rank_search := 12;
950 NEW.rank_address := NEW.rank_search;
951 ELSEIF NEW.type in ('city') THEN
952 NEW.rank_search := 16;
953 NEW.rank_address := NEW.rank_search;
954 ELSEIF NEW.type in ('island') THEN
955 NEW.rank_search := 17;
956 NEW.rank_address := 0;
957 ELSEIF NEW.type in ('town') THEN
958 NEW.rank_search := 18;
959 NEW.rank_address := 16;
960 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
961 NEW.rank_search := 19;
962 NEW.rank_address := 16;
963 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
964 NEW.rank_search := 18;
965 NEW.rank_address := 17;
966 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
967 NEW.rank_search := 17;
968 NEW.rank_address := 18;
969 ELSEIF NEW.type in ('moor') THEN
970 NEW.rank_search := 17;
971 NEW.rank_address := 0;
972 ELSEIF NEW.type in ('national_park') THEN
973 NEW.rank_search := 18;
974 NEW.rank_address := 18;
975 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
976 NEW.rank_search := 20;
977 NEW.rank_address := NEW.rank_search;
978 ELSEIF NEW.type in ('farm','locality','islet') THEN
979 NEW.rank_search := 20;
980 NEW.rank_address := 0;
981 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
982 NEW.rank_search := 22;
983 NEW.rank_address := 22;
984 ELSEIF NEW.type in ('postcode') THEN
986 NEW.name := 'ref'=>NEW.postcode;
988 IF NEW.country_code = 'gb' THEN
990 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
991 NEW.rank_search := 25;
992 NEW.rank_address := 5;
993 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
994 NEW.rank_search := 23;
995 NEW.rank_address := 5;
996 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
997 NEW.rank_search := 21;
998 NEW.rank_address := 5;
1001 ELSEIF NEW.country_code = 'de' THEN
1003 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1004 NEW.rank_search := 21;
1005 NEW.rank_address := 11;
1009 -- Guess at the postcode format and coverage (!)
1010 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1011 NEW.rank_search := 21;
1012 NEW.rank_address := 11;
1014 -- Does it look splitable into and area and local code?
1015 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1017 IF postcode IS NOT NULL THEN
1018 NEW.rank_search := 25;
1019 NEW.rank_address := 11;
1020 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1021 NEW.rank_search := 21;
1022 NEW.rank_address := 11;
1027 ELSEIF NEW.type in ('airport','street') THEN
1028 NEW.rank_search := 26;
1029 NEW.rank_address := NEW.rank_search;
1030 ELSEIF NEW.type in ('house','building') THEN
1031 NEW.rank_search := 30;
1032 NEW.rank_address := NEW.rank_search;
1033 ELSEIF NEW.type in ('houses') THEN
1034 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1035 -- insert new point into place for each derived building
1036 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1037 NEW.rank_search := 28;
1038 NEW.rank_address := 0;
1041 ELSEIF NEW.class = 'boundary' THEN
1042 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1045 NEW.rank_search := NEW.admin_level * 2;
1046 NEW.rank_address := NEW.rank_search;
1047 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1048 NEW.rank_search := 22;
1049 NEW.rank_address := NEW.rank_search;
1050 -- any feature more than 5 square miles is probably worth indexing
1051 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1052 NEW.rank_search := 22;
1053 NEW.rank_address := NEW.rank_search;
1054 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1055 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1057 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1059 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1061 ELSEIF NEW.class = 'waterway' THEN
1062 NEW.rank_address := 17;
1063 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
1064 NEW.rank_search := 27;
1065 NEW.rank_address := NEW.rank_search;
1066 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1067 NEW.rank_search := 26;
1068 NEW.rank_address := NEW.rank_search;
1069 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1070 NEW.rank_search := 4;
1071 NEW.rank_address := NEW.rank_search;
1072 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1074 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1075 NEW.rank_search := 18;
1076 NEW.rank_address := 0;
1081 IF NEW.rank_search > 30 THEN
1082 NEW.rank_search := 30;
1085 IF NEW.rank_address > 30 THEN
1086 NEW.rank_address := 30;
1089 IF (NEW.extratags -> 'capital') = 'yes' THEN
1090 NEW.rank_search := NEW.rank_search -1;
1093 -- Block import below rank 22
1094 -- IF NEW.rank_search > 22 THEN
1099 -- The following is not needed until doing diff updates, and slows the main index process down
1101 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1102 -- Performance: We just can't handle re-indexing for country level changes
1103 IF st_area(NEW.geometry) < 1 THEN
1104 -- mark items within the geometry for re-indexing
1105 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1106 -- work around bug in postgis
1107 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1108 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1109 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1110 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1113 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1115 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1116 IF NEW.type='postcode' THEN
1118 ELSEIF NEW.rank_search < 16 THEN
1120 ELSEIF NEW.rank_search < 18 THEN
1122 ELSEIF NEW.rank_search < 20 THEN
1124 ELSEIF NEW.rank_search = 21 THEN
1126 ELSEIF NEW.rank_search < 24 THEN
1128 ELSEIF NEW.rank_search < 26 THEN
1129 diameter := 0.002; -- 100 to 200 meters
1130 ELSEIF NEW.rank_search < 28 THEN
1131 diameter := 0.001; -- 50 to 100 meters
1133 IF diameter > 0 THEN
1134 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1135 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1140 -- IF NEW.rank_search < 26 THEN
1141 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1150 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1155 place_centroid GEOMETRY;
1157 search_maxdistance FLOAT[];
1158 search_mindistance FLOAT[];
1159 address_havelevel BOOLEAN[];
1160 -- search_scores wordscore[];
1161 -- search_scores_pos INTEGER;
1167 search_diameter FLOAT;
1168 search_prevdiameter FLOAT;
1169 search_maxrank INTEGER;
1170 address_maxrank INTEGER;
1171 address_street_word_id INTEGER;
1172 parent_place_id_rank INTEGER;
1177 location_rank_search INTEGER;
1178 location_distance FLOAT;
1182 name_vector INTEGER[];
1183 nameaddress_vector INTEGER[];
1188 --RAISE WARNING '%',NEW.place_id;
1189 --RAISE WARNING '%', NEW;
1191 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1192 -- Silently do nothing
1196 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1198 NEW.indexed_date = now();
1200 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1201 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1205 result := deleteSearchName(NEW.partition, NEW.place_id);
1206 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1207 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1209 -- Adding ourselves to the list simplifies address calculations later
1210 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1212 -- What level are we searching from
1213 search_maxrank := NEW.rank_search;
1215 -- Speed up searches - just use the centroid of the feature
1216 -- cheaper but less acurate
1217 place_centroid := ST_Centroid(NEW.geometry);
1219 -- Initialise the name vector using our name
1220 name_vector := make_keywords(NEW.name);
1221 nameaddress_vector := '{}'::int[];
1223 -- some tag combinations add a special id for search
1224 tagpairid := get_tagpair(NEW.class,NEW.type);
1225 IF tagpairid IS NOT NULL THEN
1226 name_vector := name_vector + tagpairid;
1230 address_havelevel[i] := false;
1233 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1235 -- For low level elements we inherit from our parent road
1236 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1238 --RAISE WARNING 'finding street for %', NEW;
1240 NEW.parent_place_id := null;
1242 -- to do that we have to find our parent road
1243 -- Copy data from linked items (points on ways, addr:street links, relations)
1244 -- Note that addr:street links can only be indexed once the street itself is indexed
1245 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1247 -- Is this node part of a relation?
1248 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1250 -- At the moment we only process one type of relation - associatedStreet
1251 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1252 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1253 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1254 --RAISE WARNING 'node in relation %',relation;
1255 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1256 and rank_search = 26 INTO NEW.parent_place_id;
1262 --RAISE WARNING 'x1';
1263 -- Is this node part of a way?
1264 FOR location IN select * from placex where osm_type = 'W'
1265 and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer] limit 10)
1267 --RAISE WARNING '%', location;
1268 -- Way IS a road then we are on it - that must be our road
1269 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1270 --RAISE WARNING 'node in way that is a street %',location;
1271 NEW.parent_place_id := location.place_id;
1274 -- Is the WAY part of a relation
1275 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1277 -- At the moment we only process one type of relation - associatedStreet
1278 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1279 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1280 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1281 --RAISE WARNING 'node in way that is in a relation %',relation;
1282 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1283 and rank_search = 26 INTO NEW.parent_place_id;
1289 -- If the way contains an explicit name of a street copy it
1290 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1291 --RAISE WARNING 'node in way that has a streetname %',location;
1292 NEW.street := location.street;
1295 -- If this way is a street interpolation line then it is probably as good as we are going to get
1296 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1297 -- Try and find a way that is close roughly parellel to this line
1298 FOR relation IN SELECT place_id FROM placex
1299 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1300 and st_geometrytype(location.geometry) in ('ST_LineString')
1301 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1302 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1303 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1305 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1306 NEW.parent_place_id := relation.place_id;
1314 --RAISE WARNING 'x2';
1316 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1317 -- Is this way part of a relation?
1318 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1320 -- At the moment we only process one type of relation - associatedStreet
1321 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1322 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1323 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1324 --RAISE WARNING 'way that is in a relation %',relation;
1325 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1326 and rank_search = 26 INTO NEW.parent_place_id;
1333 --RAISE WARNING 'x3';
1335 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1336 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1337 IF address_street_word_id IS NOT NULL THEN
1338 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1339 NEW.parent_place_id := location.place_id;
1344 --RAISE WARNING 'x4';
1346 -- Still nothing, just use the nearest road
1347 search_diameter := 0.00005;
1348 WHILE NEW.parent_place_id IS NULL AND search_diameter < 0.1 LOOP
1349 FOR location IN SELECT place_id FROM placex
1350 WHERE ST_DWithin(place_centroid, placex.geometry, search_diameter) and rank_search between 22 and 27
1351 ORDER BY ST_distance(NEW.geometry, placex.geometry) ASC limit 1
1353 NEW.parent_place_id := location.place_id;
1355 search_diameter := search_diameter * 2;
1359 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1361 -- If we didn't find any road fallback to standard method
1362 IF NEW.parent_place_id IS NOT NULL THEN
1364 -- Add the street to the address as zero distance to force to front of list
1365 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1366 address_havelevel[26] := true;
1368 -- Import address details from parent, reclculating distance in process
1369 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
1370 from place_addressline as x join placex on (address_place_id = placex.place_id)
1371 where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1373 -- Get the details of the parent road
1374 select * from search_name where place_id = NEW.parent_place_id INTO location;
1375 NEW.country_code := location.country_code;
1377 --RAISE WARNING '%', NEW.name;
1378 -- If there is no name it isn't searchable, don't bother to create a search record
1379 IF NEW.name is NULL THEN
1383 -- Merge address from parent
1384 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1386 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1387 -- Just be happy with inheriting from parent road only
1389 IF NEW.rank_search <= 25 THEN
1390 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1393 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid);
1400 RAISE WARNING ' INDEXING: %',NEW;
1402 NEW.parent_place_id = 0;
1403 parent_place_id_rank = 0;
1405 -- convert isin to array of tokenids
1406 isin_tokens := '{}'::int[];
1407 IF NEW.isin IS NOT NULL THEN
1408 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1409 IF array_upper(isin, 1) IS NOT NULL THEN
1410 FOR i IN 1..array_upper(isin, 1) LOOP
1411 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1412 IF address_street_word_id IS NOT NULL THEN
1413 isin_tokens := isin_tokens + address_street_word_id;
1417 isin_tokens := uniq(sort(isin_tokens));
1419 IF NEW.postcode IS NOT NULL THEN
1420 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1421 IF array_upper(isin, 1) IS NOT NULL THEN
1422 FOR i IN 1..array_upper(isin, 1) LOOP
1423 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1424 IF address_street_word_id IS NOT NULL THEN
1425 isin_tokens := isin_tokens + address_street_word_id;
1429 isin_tokens := uniq(sort(isin_tokens));
1432 -- try using the isin value to find parent places
1433 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1434 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1435 --RAISE WARNING ' ISIN: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1437 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1438 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1439 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1440 address_havelevel[location.rank_address] := true;
1442 IF location.rank_address > parent_place_id_rank THEN
1443 NEW.parent_place_id = location.place_id;
1444 parent_place_id_rank = location.rank_address;
1452 -- Process area matches
1453 location_rank_search := 100;
1454 location_distance := 0;
1455 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1457 --RAISE WARNING ' AREA: %',location;
1459 IF location.rank_search < location_rank_search THEN
1460 location_rank_search := location.rank_search;
1461 location_distance := location.distance * 1.5;
1464 IF location.distance < location_distance THEN
1466 -- Add it to the list of search terms
1467 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1468 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1469 address_havelevel[location.rank_address] := true;
1471 IF location.rank_address > parent_place_id_rank THEN
1472 NEW.parent_place_id = location.place_id;
1473 parent_place_id_rank = location.rank_address;
1480 -- for long ways we should add search terms for the entire length
1481 IF st_length(NEW.geometry) > 0.05 THEN
1483 location_rank_search := 100;
1484 location_distance := 0;
1486 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1488 IF location.rank_search < location_rank_search THEN
1489 location_rank_search := location.rank_search;
1490 location_distance := location.distance * 1.5;
1493 IF location.distance < location_distance THEN
1495 -- Add it to the list of search terms
1496 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1497 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1505 -- if we have a name add this to the name search table
1506 IF NEW.name IS NOT NULL THEN
1508 IF NEW.rank_search <= 25 THEN
1509 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1512 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, place_centroid);
1514 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1524 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1530 IF OLD.rank_address < 30 THEN
1532 -- mark everything linked to this place for re-indexing
1533 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1534 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1536 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1540 IF OLD.rank_address < 26 THEN
1541 b := deleteLocationArea(OLD.partition, OLD.place_id);
1544 IF OLD.name is not null THEN
1545 b := deleteSearchName(OLD.partition, OLD.place_id);
1548 DELETE FROM place_addressline where place_id = OLD.place_id;
1556 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1562 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1563 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1570 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1575 existingplacex RECORD;
1576 existinggeometry GEOMETRY;
1577 existingplace_id INTEGER;
1581 IF FALSE AND NEW.osm_type = 'R' THEN
1582 RAISE WARNING '-----------------------------------------------------------------------------------';
1583 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1584 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;
1585 RAISE WARNING '%', existingplacex;
1588 -- Just block these - lots and pointless
1589 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1592 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1596 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
1597 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1601 -- Patch in additional country names
1602 -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1603 IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1604 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1607 -- Have we already done this place?
1608 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;
1610 -- Get the existing place_id
1611 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;
1613 -- Handle a place changing type by removing the old data
1614 -- My generated 'place' types are causing havok because they overlap with real tags
1615 -- TODO: move them to their own special purpose tag to avoid collisions
1616 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1617 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');
1620 -- RAISE WARNING 'Existing: %',existing.place_id;
1622 -- 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
1623 IF existing.osm_type IS NULL
1624 OR existingplacex.osm_type IS NULL
1625 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1626 -- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1627 OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1628 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1631 -- IF existing.osm_type IS NULL THEN
1632 -- RAISE WARNING 'no existing place';
1634 -- IF existingplacex.osm_type IS NULL THEN
1635 -- RAISE WARNING 'no existing placex %', existingplacex;
1639 -- RAISE WARNING 'delete and replace';
1641 IF existing.osm_type IS NOT NULL THEN
1642 -- 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;
1643 IF existing.rank_search < 26 THEN
1644 -- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1646 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1649 -- RAISE WARNING 'delete and replace2';
1651 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1652 insert into placex values (NEW.place_id
1664 ,NEW.parent_place_id
1671 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1676 -- Various ways to do the update
1678 -- Debug, what's changed?
1679 IF FALSE AND existing.rank_search < 26 THEN
1680 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1681 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1683 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1684 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1686 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1687 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1689 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1690 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1692 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1693 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1695 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1696 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1700 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1701 IF existing.geometry != NEW.geometry
1702 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1703 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1706 -- IF existing.rank_search < 26 THEN
1707 -- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1710 -- Get the version of the geometry actually used (in placex table)
1711 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;
1713 -- Performance limit
1714 IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1716 -- 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
1717 update placex set indexed_status = 2 where indexed_status = 0 and
1718 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1719 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1720 AND rank_search > NEW.rank_search;
1722 update placex set indexed_status = 2 where indexed_status = 0 and
1723 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1724 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1725 AND rank_search > NEW.rank_search;
1731 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1732 IF existingplacex.rank_search < 26
1733 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1734 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1735 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1736 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1737 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1738 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1741 -- IF existing.rank_search < 26 THEN
1742 -- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1745 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1747 IF st_area(NEW.geometry) < 0.5 THEN
1748 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1749 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1756 -- Anything else has changed - reindex the lot
1757 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1758 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1759 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1760 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1761 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1762 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1764 -- IF existing.rank_search < 26 THEN
1765 -- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1768 -- performance, can't take the load of re-indexing a whole country / huge area
1769 IF st_area(NEW.geometry) < 0.5 THEN
1770 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1771 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1778 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1779 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1780 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1781 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1782 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1783 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1784 OR existing.geometry != NEW.geometry
1789 housenumber = NEW.housenumber,
1790 street = NEW.street,
1792 postcode = NEW.postcode,
1793 country_code = NEW.country_code,
1794 parent_place_id = null,
1795 geometry = NEW.geometry
1796 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1800 housenumber = NEW.housenumber,
1801 street = NEW.street,
1803 postcode = NEW.postcode,
1804 country_code = NEW.country_code,
1805 parent_place_id = null,
1807 geometry = NEW.geometry
1808 where place_id = existingplacex.place_id;
1810 result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1814 -- Abort the add (we modified the existing place instead)
1818 $$ LANGUAGE plpgsql;
1820 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1827 IF name is null THEN
1831 search := languagepref;
1833 FOR j IN 1..array_upper(search, 1) LOOP
1834 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1835 return trim(name->search[j]);
1842 LANGUAGE plpgsql IMMUTABLE;
1844 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1847 searchnodes INTEGER[];
1852 searchnodes := '{}';
1853 FOR j IN 1..array_upper(way_ids, 1) LOOP
1855 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1857 searchnodes := searchnodes | location.nodes;
1861 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1864 LANGUAGE plpgsql IMMUTABLE;
1866 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT
1877 search := ARRAY['ref'];
1880 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1883 select rank_address,name,distance,length(name::text) as namelength
1884 from place_addressline join placex on (address_place_id = placex.place_id)
1885 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1886 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1888 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1889 FOR j IN 1..array_upper(search, 1) LOOP
1890 FOR k IN 1..array_upper(location.name, 1) LOOP
1891 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
1892 result[(100 - location.rank_address)] := trim(location.name[k].value);
1893 found := location.rank_address;
1900 RETURN array_to_string(result,', ');
1905 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT
1912 searchcountrycode varchar(2);
1913 searchhousenumber TEXT;
1914 searchrankaddress INTEGER;
1915 searchpostcode TEXT;
1919 search := languagepref;
1922 select country_code,housenumber,rank_address,postcode from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress,searchpostcode;
1925 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1926 CASE WHEN type = 'postcode' THEN 'name' => postcode ELSE name END as name,
1927 distance,length(name::text) as namelength
1928 from place_addressline join placex on (address_place_id = placex.place_id)
1929 where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
1930 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1931 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1933 IF array_upper(search, 1) IS NOT NULL AND location.name IS NOT NULL THEN
1934 FOR j IN 1..array_upper(search, 1) LOOP
1935 IF (found > location.rank_address AND location.name ? search[j] AND location.name -> search[j] != ''
1936 AND NOT result && ARRAY[location.name -> search[j]]) THEN
1937 result[(100 - location.rank_address)] := trim(location.name -> search[j]);
1938 found := location.rank_address;
1944 IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
1945 IF result[(100 - 28)] IS NOT NULL THEN
1946 result[(100 - 29)] := result[(100 - 28)];
1948 result[(100 - 28)] := searchhousenumber;
1951 IF searchpostcode IS NOT NULL THEN
1952 result[(100 - 5)] := searchpostcode;
1955 -- No country polygon - add it from the country_code
1957 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
1958 where place_id = for_place_id limit 1 INTO location;
1959 IF location IS NOT NULL THEN
1960 result[(100 - 4)] := trim(location.name);
1964 RETURN array_to_string(result,', ');
1969 CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT[]
1976 searchcountrycode varchar(2);
1977 searchhousenumber TEXT;
1981 search := languagepref;
1984 UPDATE placex set indexed_status = 0 where indexed_status > 0 and place_id = for_place_id;
1986 select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
1989 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
1990 name,distance,length(name::text) as namelength
1991 from place_addressline join placex on (address_place_id = placex.place_id)
1992 where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
1993 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
1994 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
1996 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1997 FOR j IN 1..array_upper(search, 1) LOOP
1998 FOR k IN 1..array_upper(location.name, 1) LOOP
1999 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
2000 result[(100 - location.rank_address)] := trim(location.name[k].value);
2001 found := location.rank_address;
2008 IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
2009 result[(100 - 28)] := searchhousenumber;
2012 -- No country polygon - add it from the country_code
2014 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
2015 where place_id = for_place_id limit 1 INTO location;
2016 IF location IS NOT NULL THEN
2017 result[(100 - 4)] := trim(location.name);
2026 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
2029 result place_boundingbox;
2030 numfeatures integer;
2032 select * from place_boundingbox into result where place_id = search_place_id;
2033 IF result.place_id IS NULL THEN
2034 -- remove isaddress = true because if there is a matching polygon it always wins
2035 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2036 insert into place_boundingbox select place_id,
2037 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2038 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2039 numfeatures, ST_Area(geometry),
2040 geometry as area from location_area where place_id = search_place_id;
2041 select * from place_boundingbox into result where place_id = search_place_id;
2043 IF result.place_id IS NULL THEN
2045 insert into place_boundingbox select address_place_id,
2046 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2047 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2048 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2049 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2050 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)
2051 where address_place_id = search_place_id
2052 -- and (isaddress = true OR place_id = search_place_id)
2053 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2054 group by address_place_id limit 1;
2055 select * from place_boundingbox into result where place_id = search_place_id;
2062 -- don't do the operation if it would be slow
2063 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
2066 result place_boundingbox;
2067 numfeatures integer;
2070 select * from place_boundingbox into result where place_id = search_place_id;
2071 IF result IS NULL AND rank > 14 THEN
2072 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2073 insert into place_boundingbox select place_id,
2074 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2075 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2076 numfeatures, ST_Area(geometry),
2077 geometry as area from location_area where place_id = search_place_id;
2078 select * from place_boundingbox into result where place_id = search_place_id;
2080 IF result IS NULL THEN
2081 select rank_search from placex where place_id = search_place_id into rank;
2084 insert into place_boundingbox select address_place_id,
2085 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2086 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2087 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2088 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2089 from place_addressline join placex using (place_id)
2090 where address_place_id = search_place_id
2091 and (isaddress = true OR place_id = search_place_id)
2092 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2093 group by address_place_id limit 1;
2094 select * from place_boundingbox into result where place_id = search_place_id;
2102 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2105 result place_boundingbox;
2106 numfeatures integer;
2110 housenumber = place.housenumber,
2111 street = place.street,
2113 postcode = place.postcode,
2114 country_code = place.country_code,
2115 parent_place_id = null,
2118 where placex.place_id = search_place_id
2119 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2120 and place.class = placex.class and place.type = placex.type;
2121 update placex set indexed_status = 1 where place_id = search_place_id;
2122 update placex set indexed_status = 0 where place_id = search_place_id;
2128 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2131 result place_boundingbox;
2132 numfeatures integer;
2136 housenumber = place.housenumber,
2137 street = place.street,
2139 postcode = place.postcode,
2140 country_code = place.country_code,
2141 parent_place_id = null
2143 where placex.place_id = search_place_id
2144 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2145 and place.class = placex.class and place.type = placex.type;
2146 update placex set indexed_status = 2 where place_id = search_place_id;
2147 update placex set indexed_status = 0 where place_id = search_place_id;
2153 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2159 ELSEIF rank < 4 THEN
2161 ELSEIF rank < 8 THEN
2163 ELSEIF rank < 12 THEN
2165 ELSEIF rank < 16 THEN
2167 ELSEIF rank = 16 THEN
2169 ELSEIF rank = 17 THEN
2170 RETURN 'Town / Island';
2171 ELSEIF rank = 18 THEN
2172 RETURN 'Village / Hamlet';
2173 ELSEIF rank = 20 THEN
2175 ELSEIF rank = 21 THEN
2176 RETURN 'Postcode Area';
2177 ELSEIF rank = 22 THEN
2178 RETURN 'Croft / Farm / Locality / Islet';
2179 ELSEIF rank = 23 THEN
2180 RETURN 'Postcode Area';
2181 ELSEIF rank = 25 THEN
2182 RETURN 'Postcode Point';
2183 ELSEIF rank = 26 THEN
2184 RETURN 'Street / Major Landmark';
2185 ELSEIF rank = 27 THEN
2186 RETURN 'Minory Street / Path';
2187 ELSEIF rank = 28 THEN
2188 RETURN 'House / Building';
2190 RETURN 'Other: '||rank;
2197 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2203 ELSEIF rank < 2 THEN
2205 ELSEIF rank < 4 THEN
2207 ELSEIF rank = 5 THEN
2209 ELSEIF rank < 8 THEN
2211 ELSEIF rank < 12 THEN
2213 ELSEIF rank < 16 THEN
2215 ELSEIF rank = 16 THEN
2217 ELSEIF rank = 17 THEN
2218 RETURN 'Town / Village / Hamlet';
2219 ELSEIF rank = 20 THEN
2221 ELSEIF rank = 21 THEN
2222 RETURN 'Postcode Area';
2223 ELSEIF rank = 22 THEN
2224 RETURN 'Croft / Farm / Locality / Islet';
2225 ELSEIF rank = 23 THEN
2226 RETURN 'Postcode Area';
2227 ELSEIF rank = 25 THEN
2228 RETURN 'Postcode Point';
2229 ELSEIF rank = 26 THEN
2230 RETURN 'Street / Major Landmark';
2231 ELSEIF rank = 27 THEN
2232 RETURN 'Minory Street / Path';
2233 ELSEIF rank = 28 THEN
2234 RETURN 'House / Building';
2236 RETURN 'Other: '||rank;
2243 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2250 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2251 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2258 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2266 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2268 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2269 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2271 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2279 CREATE AGGREGATE array_agg(INT[])
2286 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2287 in_endnumber INTEGER, interpolationtype TEXT,
2288 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2292 startnumber INTEGER;
2297 numberrange INTEGER;
2298 rangestartnumber INTEGER;
2299 place_centroid GEOMETRY;
2301 parent_place_id INTEGER;
2303 address_street_word_id INTEGER;
2307 IF in_endnumber > in_startnumber THEN
2308 startnumber = in_startnumber;
2309 endnumber = in_endnumber;
2311 startnumber = in_endnumber;
2312 endnumber = in_startnumber;
2315 numberrange := endnumber - startnumber;
2316 rangestartnumber := startnumber;
2318 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2319 startnumber := startnumber + 1;
2322 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2324 ELSE -- everything else assumed to be 'all'
2329 -- Filter out really broken tiger data
2330 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500) AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2331 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,ST_length(linegeo)/(numberrange::float/stepsize::float);
2335 place_centroid := ST_Centroid(linegeo);
2336 partition := get_partition(place_centroid, 'us');
2337 parent_place_id := null;
2338 address_street_word_id := get_name_id(make_standard_name(in_street));
2339 IF address_street_word_id IS NOT NULL THEN
2340 FOR location IN SELECT * from getNearestNamedRoadFeature(partition, place_centroid, address_street_word_id) LOOP
2341 parent_place_id := location.place_id;
2346 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2347 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2348 values (nextval('seq_place'), 2, parent_place_id, housenum, in_postcode,
2349 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2350 newpoints := newpoints + 1;