1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
56 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
57 NEWgeometry := ST_buffer(NEWgeometry,0);
58 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
62 RETURN (partition*1000000) + (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
72 -- RAISE WARNING '%',osmid;
77 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
78 NEWgeometry := ST_buffer(NEWgeometry,0);
79 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
83 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
86 LANGUAGE plpgsql IMMUTABLE;
88 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
89 AS '{modulepath}/nominatim.so', 'transliteration'
90 LANGUAGE c IMMUTABLE STRICT;
92 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
93 AS '{modulepath}/nominatim.so', 'gettokenstring'
94 LANGUAGE c IMMUTABLE STRICT;
96 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
101 o := gettokenstring(transliteration(name));
102 RETURN trim(substr(o,1,length(o)));
105 LANGUAGE 'plpgsql' IMMUTABLE;
107 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
112 return_word_id INTEGER;
114 lookup_token := trim(lookup_word);
115 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
116 IF return_word_id IS NULL THEN
117 return_word_id := nextval('seq_word');
118 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
120 RETURN return_word_id;
125 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
130 return_word_id INTEGER;
132 lookup_token := ' '||trim(lookup_word);
133 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
134 IF return_word_id IS NULL THEN
135 return_word_id := nextval('seq_word');
136 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
138 RETURN return_word_id;
143 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
148 return_word_id INTEGER;
150 lookup_token := ' '||trim(lookup_word);
151 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
152 IF return_word_id IS NULL THEN
153 return_word_id := nextval('seq_word');
154 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
156 RETURN return_word_id;
161 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
174 RETURN return_word_id;
179 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
184 return_word_id INTEGER;
186 lookup_token := lookup_class||'='||lookup_type;
187 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
188 IF return_word_id IS NULL THEN
189 return_word_id := nextval('seq_word');
190 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
192 RETURN return_word_id;
197 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
202 return_word_id INTEGER;
204 lookup_token := lookup_class||'='||lookup_type;
205 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
206 RETURN return_word_id;
211 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
216 return_word_id INTEGER;
218 lookup_token := ' '||trim(lookup_word);
219 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
220 IF return_word_id IS NULL THEN
221 return_word_id := nextval('seq_word');
222 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
224 RETURN return_word_id;
229 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
234 nospace_lookup_token TEXT;
235 return_word_id INTEGER;
237 lookup_token := ' '||trim(lookup_word);
238 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
239 IF return_word_id IS NULL THEN
240 return_word_id := nextval('seq_word');
241 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
242 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
243 -- IF ' '||nospace_lookup_token != lookup_token THEN
244 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
247 RETURN return_word_id;
252 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
257 RETURN getorcreate_name_id(lookup_word, '');
262 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
267 return_word_id INTEGER;
269 lookup_token := trim(lookup_word);
270 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
271 RETURN return_word_id;
274 LANGUAGE plpgsql IMMUTABLE;
276 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
281 return_word_id INTEGER;
283 lookup_token := ' '||trim(lookup_word);
284 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
285 RETURN return_word_id;
288 LANGUAGE plpgsql IMMUTABLE;
290 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
297 IF array_upper(a, 1) IS NULL THEN
300 IF array_upper(b, 1) IS NULL THEN
304 FOR i IN 1..array_upper(b, 1) LOOP
305 IF NOT (ARRAY[b[i]] && r) THEN
312 LANGUAGE plpgsql IMMUTABLE;
314 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
324 result := '{}'::INTEGER[];
326 FOR item IN SELECT (each(src)).* LOOP
328 s := make_standard_name(item.value);
330 w := getorcreate_name_id(s, item.value);
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 -- RAISE WARNING 'Spliting geometry: % to %, % to %', xmin, xmax, ymin, ymax;
601 FOR lon IN xmin..(xmax-1) LOOP
602 FOR lat IN ymin..(ymax-1) LOOP
603 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
604 IF st_intersects(geometry, secbox) THEN
605 secgeo := st_intersection(geometry, secbox);
606 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
607 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
614 ELSEIF rank_search < 26 THEN
617 IF rank_address = 0 THEN
619 ELSEIF rank_search <= 14 THEN
621 ELSEIF rank_search <= 15 THEN
623 ELSEIF rank_search <= 16 THEN
625 ELSEIF rank_search <= 17 THEN
627 ELSEIF rank_search <= 21 THEN
629 ELSEIF rank_search = 25 THEN
633 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
635 secgeo := ST_Buffer(geometry, diameter);
636 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
641 secgeo := ST_Buffer(geometry, 0.0002);
642 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
645 secgeo := ST_Buffer(geometry, 0.001);
646 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
655 CREATE OR REPLACE FUNCTION update_location(
658 place_country_code varchar(2),
661 rank_address INTEGER,
669 b := deleteLocationArea(partition, place_id);
670 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
671 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
676 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id INTEGER, to_add INTEGER[])
687 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
688 FOR childplace IN select * from search_name,place_addressline
689 where address_place_id = parent_place_id
690 and search_name.place_id = place_addressline.place_id
692 delete from search_name where place_id = childplace.place_id;
693 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
694 IF childplace.place_id = parent_place_id THEN
695 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
697 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
698 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
699 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
707 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id INTEGER, name hstore) RETURNS BOOLEAN
710 newkeywords INTEGER[];
711 addedkeywords INTEGER[];
712 removedkeywords INTEGER[];
716 newkeywords := make_keywords(name);
717 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
718 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
719 where place_id = OLD_place_id into addedkeywords, removedkeywords;
721 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
723 IF #removedkeywords > 0 THEN
724 -- abort due to tokens removed
728 IF #addedkeywords > 0 THEN
729 -- short circuit - no changes
733 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
734 RETURN search_name_add_words(OLD_place_id, addedkeywords);
740 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
752 orginalstartnumber INTEGER;
753 originalnumberrange INTEGER;
756 search_place_id INTEGER;
759 havefirstpoint BOOLEAN;
763 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
765 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
766 select nodes from planet_osm_ways where id = wayid INTO waynodes;
767 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
768 IF array_upper(waynodes, 1) IS NOT NULL THEN
770 havefirstpoint := false;
772 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
774 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
775 IF search_place_id IS NULL THEN
776 -- null record of right type
777 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
778 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
780 select * from placex where place_id = search_place_id INTO nextnode;
783 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
785 IF havefirstpoint THEN
787 -- add point to the line string
788 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
789 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
791 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
793 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
795 IF startnumber != endnumber THEN
797 linestr := linestr || ')';
798 --RAISE WARNING 'linestr %',linestr;
799 linegeo := ST_GeomFromText(linestr,4326);
800 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
801 IF (startnumber > endnumber) THEN
802 housenum := endnumber;
803 endnumber := startnumber;
804 startnumber := housenum;
805 linegeo := ST_Reverse(linegeo);
807 orginalstartnumber := startnumber;
808 originalnumberrange := endnumber - startnumber;
810 -- Too much broken data worldwide for this test to be worth using
811 -- IF originalnumberrange > 500 THEN
812 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
815 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
816 startnumber := startnumber + 1;
819 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
820 startnumber := startnumber + 2;
822 ELSE -- everything else assumed to be 'all'
823 startnumber := startnumber + 1;
827 endnumber := endnumber - 1;
828 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
829 FOR housenum IN startnumber..endnumber BY stepsize LOOP
830 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
831 -- ideally postcodes should move up to the way
832 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
833 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
834 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
835 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));
836 newpoints := newpoints + 1;
837 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
840 havefirstpoint := false;
844 IF NOT havefirstpoint THEN
845 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
846 IF startnumber IS NOT NULL AND startnumber > 0 THEN
847 havefirstpoint := true;
848 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
849 prevnode := nextnode;
851 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
857 --RAISE WARNING 'interpolation points % ',newpoints;
864 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
870 country_code VARCHAR(2);
871 default_language VARCHAR(10);
874 -- RAISE WARNING '%',NEW.osm_id;
877 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
878 -- RAISE WARNING 'bad highway %',NEW.osm_id;
881 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
882 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
886 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
887 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
888 -- RAISE WARNING 'invalid geometry %',NEW.osm_id;
892 IF NEW.osm_type = 'R' THEN
893 -- invalid multipolygons can crash postgis, don't even bother to try!
896 NEW.geometry := ST_buffer(NEW.geometry,0);
897 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
898 -- RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
903 NEW.place_id := nextval('seq_place');
904 NEW.indexed_status := 1; --STATUS_NEW
906 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
907 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
908 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
910 -- copy 'name' to or from the default language (if there is a default language)
911 IF NEW.name is not null AND array_upper(%#NEW.name,1) > 1 THEN
912 default_language := get_country_language_code(NEW.country_code);
913 IF default_language IS NOT NULL THEN
914 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
915 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
916 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
917 NEW.name := NEW.name || ('name' => (NEW.name -> 'name:'||default_language));
922 IF NEW.admin_level > 15 THEN
923 NEW.admin_level := 15;
926 IF NEW.housenumber IS NOT NULL THEN
927 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
930 IF NEW.osm_type = 'X' THEN
931 -- E'X'ternal records should already be in the right format so do nothing
933 NEW.rank_search := 30;
934 NEW.rank_address := NEW.rank_search;
936 -- By doing in postgres we have the country available to us - currently only used for postcode
937 IF NEW.class = 'place' THEN
938 IF NEW.type in ('continent') THEN
939 NEW.rank_search := 2;
940 NEW.rank_address := NEW.rank_search;
941 ELSEIF NEW.type in ('sea') THEN
942 NEW.rank_search := 2;
943 NEW.rank_address := 0;
944 ELSEIF NEW.type in ('country') THEN
945 NEW.rank_search := 4;
946 NEW.rank_address := NEW.rank_search;
947 ELSEIF NEW.type in ('state') THEN
948 NEW.rank_search := 8;
949 NEW.rank_address := NEW.rank_search;
950 ELSEIF NEW.type in ('region') THEN
951 NEW.rank_search := 10;
952 NEW.rank_address := NEW.rank_search;
953 ELSEIF NEW.type in ('county') THEN
954 NEW.rank_search := 12;
955 NEW.rank_address := NEW.rank_search;
956 ELSEIF NEW.type in ('city') THEN
957 NEW.rank_search := 16;
958 NEW.rank_address := NEW.rank_search;
959 ELSEIF NEW.type in ('island') THEN
960 NEW.rank_search := 17;
961 NEW.rank_address := 0;
962 ELSEIF NEW.type in ('town') THEN
963 NEW.rank_search := 18;
964 NEW.rank_address := 16;
965 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
966 NEW.rank_search := 19;
967 NEW.rank_address := 16;
968 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
969 NEW.rank_search := 18;
970 NEW.rank_address := 17;
971 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
972 NEW.rank_search := 17;
973 NEW.rank_address := 18;
974 ELSEIF NEW.type in ('moor') THEN
975 NEW.rank_search := 17;
976 NEW.rank_address := 0;
977 ELSEIF NEW.type in ('national_park') THEN
978 NEW.rank_search := 18;
979 NEW.rank_address := 18;
980 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
981 NEW.rank_search := 20;
982 NEW.rank_address := NEW.rank_search;
983 ELSEIF NEW.type in ('farm','locality','islet') THEN
984 NEW.rank_search := 20;
985 NEW.rank_address := 0;
986 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
987 NEW.rank_search := 22;
988 NEW.rank_address := 22;
989 ELSEIF NEW.type in ('postcode') THEN
991 NEW.name := 'ref'=>NEW.postcode;
993 IF NEW.country_code = 'gb' THEN
995 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
996 NEW.rank_search := 25;
997 NEW.rank_address := 5;
998 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
999 NEW.rank_search := 23;
1000 NEW.rank_address := 5;
1001 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1002 NEW.rank_search := 21;
1003 NEW.rank_address := 5;
1006 ELSEIF NEW.country_code = 'de' THEN
1008 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1009 NEW.rank_search := 21;
1010 NEW.rank_address := 11;
1014 -- Guess at the postcode format and coverage (!)
1015 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1016 NEW.rank_search := 21;
1017 NEW.rank_address := 11;
1019 -- Does it look splitable into and area and local code?
1020 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1022 IF postcode IS NOT NULL THEN
1023 NEW.rank_search := 25;
1024 NEW.rank_address := 11;
1025 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1026 NEW.rank_search := 21;
1027 NEW.rank_address := 11;
1032 ELSEIF NEW.type in ('airport','street') THEN
1033 NEW.rank_search := 26;
1034 NEW.rank_address := NEW.rank_search;
1035 ELSEIF NEW.type in ('house','building') THEN
1036 NEW.rank_search := 30;
1037 NEW.rank_address := NEW.rank_search;
1038 ELSEIF NEW.type in ('houses') THEN
1039 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1040 -- insert new point into place for each derived building
1041 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1042 NEW.rank_search := 28;
1043 NEW.rank_address := 0;
1046 ELSEIF NEW.class = 'boundary' THEN
1047 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1048 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1051 NEW.rank_search := NEW.admin_level * 2;
1052 NEW.rank_address := NEW.rank_search;
1053 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1054 NEW.rank_search := 22;
1055 NEW.rank_address := NEW.rank_search;
1056 -- any feature more than 5 square miles is probably worth indexing
1057 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1058 NEW.rank_search := 22;
1059 NEW.rank_address := NEW.rank_search;
1060 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1061 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1062 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1064 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1066 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1068 ELSEIF NEW.class = 'waterway' THEN
1069 NEW.rank_address := 17;
1070 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
1071 NEW.rank_search := 27;
1072 NEW.rank_address := NEW.rank_search;
1073 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1074 NEW.rank_search := 26;
1075 NEW.rank_address := NEW.rank_search;
1076 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1077 NEW.rank_search := 4;
1078 NEW.rank_address := NEW.rank_search;
1079 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1081 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1082 NEW.rank_search := 18;
1083 NEW.rank_address := 0;
1088 IF NEW.rank_search > 30 THEN
1089 NEW.rank_search := 30;
1092 IF NEW.rank_address > 30 THEN
1093 NEW.rank_address := 30;
1096 IF (NEW.extratags -> 'capital') = 'yes' THEN
1097 NEW.rank_search := NEW.rank_search -1;
1100 -- Block import below rank 22
1101 -- IF NEW.rank_search > 22 THEN
1105 RETURN NEW; -- The following is not needed until doing diff updates, and slows the main index process down
1107 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1108 -- Performance: We just can't handle re-indexing for country level changes
1109 IF st_area(NEW.geometry) < 1 THEN
1110 -- mark items within the geometry for re-indexing
1111 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1112 -- work around bug in postgis
1113 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1114 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point';
1115 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1116 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point';
1119 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1121 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1122 IF NEW.type='postcode' THEN
1124 ELSEIF NEW.rank_search < 16 THEN
1126 ELSEIF NEW.rank_search < 18 THEN
1128 ELSEIF NEW.rank_search < 20 THEN
1130 ELSEIF NEW.rank_search = 21 THEN
1132 ELSEIF NEW.rank_search < 24 THEN
1134 ELSEIF NEW.rank_search < 26 THEN
1135 diameter := 0.002; -- 100 to 200 meters
1136 ELSEIF NEW.rank_search < 28 THEN
1137 diameter := 0.001; -- 50 to 100 meters
1139 IF diameter > 0 THEN
1140 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1141 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1146 -- IF NEW.rank_search < 26 THEN
1147 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1156 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1161 place_centroid GEOMETRY;
1163 search_maxdistance FLOAT[];
1164 search_mindistance FLOAT[];
1165 address_havelevel BOOLEAN[];
1166 -- search_scores wordscore[];
1167 -- search_scores_pos INTEGER;
1174 search_diameter FLOAT;
1175 search_prevdiameter FLOAT;
1176 search_maxrank INTEGER;
1177 address_maxrank INTEGER;
1178 address_street_word_id INTEGER;
1179 parent_place_id_rank INTEGER;
1184 location_rank_search INTEGER;
1185 location_distance FLOAT;
1189 name_vector INTEGER[];
1190 nameaddress_vector INTEGER[];
1195 --RAISE WARNING '%',NEW.place_id;
1196 --RAISE WARNING '%', NEW;
1198 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1199 -- Silently do nothing
1204 IF OLD.indexed_status = 100 THEN
1205 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1209 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1211 NEW.indexed_date = now();
1213 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1214 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1218 result := deleteSearchName(NEW.partition, NEW.place_id);
1219 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1220 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1221 result := deleteRoad(NEW.partition, NEW.place_id);
1222 result := deleteLocationArea(NEW.partition, NEW.place_id);
1224 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1225 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
1226 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1228 -- Adding ourselves to the list simplifies address calculations later
1229 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1231 -- What level are we searching from
1232 search_maxrank := NEW.rank_search;
1234 -- Speed up searches - just use the centroid of the feature
1235 -- cheaper but less acurate
1236 place_centroid := ST_Centroid(NEW.geometry);
1238 -- Initialise the name vector using our name
1239 name_vector := make_keywords(NEW.name);
1240 nameaddress_vector := '{}'::int[];
1242 -- some tag combinations add a special id for search
1243 tagpairid := get_tagpair(NEW.class,NEW.type);
1244 IF tagpairid IS NOT NULL THEN
1245 name_vector := name_vector + tagpairid;
1249 address_havelevel[i] := false;
1252 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1254 -- For low level elements we inherit from our parent road
1255 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1257 --RAISE WARNING 'finding street for %', NEW;
1259 NEW.parent_place_id := null;
1261 -- to do that we have to find our parent road
1262 -- Copy data from linked items (points on ways, addr:street links, relations)
1263 -- Note that addr:street links can only be indexed once the street itself is indexed
1264 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1266 -- Is this node part of a relation?
1267 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1269 -- At the moment we only process one type of relation - associatedStreet
1270 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1271 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1272 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1273 --RAISE WARNING 'node in relation %',relation;
1274 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1275 and rank_search = 26 INTO NEW.parent_place_id;
1281 --RAISE WARNING 'x1';
1282 -- Is this node part of a way?
1283 FOR way IN select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer] LOOP
1284 --RAISE WARNING '%', way;
1285 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1287 --RAISE WARNING '%', location;
1288 -- Way IS a road then we are on it - that must be our road
1289 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1290 --RAISE WARNING 'node in way that is a street %',location;
1291 NEW.parent_place_id := location.place_id;
1294 -- Is the WAY part of a relation
1295 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1297 -- At the moment we only process one type of relation - associatedStreet
1298 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1299 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1300 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1301 --RAISE WARNING 'node in way that is in a relation %',relation;
1302 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1303 and rank_search = 26 INTO NEW.parent_place_id;
1309 -- If the way contains an explicit name of a street copy it
1310 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1311 --RAISE WARNING 'node in way that has a streetname %',location;
1312 NEW.street := location.street;
1315 -- If this way is a street interpolation line then it is probably as good as we are going to get
1316 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1317 -- Try and find a way that is close roughly parellel to this line
1318 FOR relation IN SELECT place_id FROM placex
1319 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1320 and st_geometrytype(location.geometry) in ('ST_LineString')
1321 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1322 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1323 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1325 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1326 NEW.parent_place_id := relation.place_id;
1335 --RAISE WARNING 'x2';
1337 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1338 -- Is this way part of a relation?
1339 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1341 -- At the moment we only process one type of relation - associatedStreet
1342 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1343 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1344 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1345 --RAISE WARNING 'way that is in a relation %',relation;
1346 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1347 and rank_search = 26 INTO NEW.parent_place_id;
1354 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1356 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1357 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1358 IF address_street_word_id IS NOT NULL THEN
1359 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1360 NEW.parent_place_id := location.place_id;
1365 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1366 -- Still nothing, just use the nearest road
1367 IF NEW.parent_place_id IS NULL THEN
1368 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1369 NEW.parent_place_id := location.place_id;
1374 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1376 -- If we didn't find any road fallback to standard method
1377 IF NEW.parent_place_id IS NOT NULL THEN
1379 -- Add the street to the address as zero distance to force to front of list
1380 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1381 address_havelevel[26] := true;
1383 -- Import address details from parent, reclculating distance in process
1384 -- 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
1385 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1386 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1388 -- Get the details of the parent road
1389 select * from search_name where place_id = NEW.parent_place_id INTO location;
1390 NEW.country_code := location.country_code;
1392 --RAISE WARNING '%', NEW.name;
1393 -- If there is no name it isn't searchable, don't bother to create a search record
1394 IF NEW.name is NULL THEN
1398 -- Merge address from parent
1399 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1401 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1402 -- Just be happy with inheriting from parent road only
1404 IF NEW.rank_search <= 25 THEN
1405 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1408 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1415 -- RAISE WARNING ' INDEXING: %',NEW;
1417 NEW.parent_place_id = 0;
1418 parent_place_id_rank = 0;
1420 -- convert isin to array of tokenids
1421 isin_tokens := '{}'::int[];
1422 IF NEW.isin IS NOT NULL THEN
1423 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1424 IF array_upper(isin, 1) IS NOT NULL THEN
1425 FOR i IN 1..array_upper(isin, 1) LOOP
1426 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1427 IF address_street_word_id IS NOT NULL THEN
1428 isin_tokens := isin_tokens + address_street_word_id;
1432 isin_tokens := uniq(sort(isin_tokens));
1434 IF NEW.postcode IS NOT NULL THEN
1435 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1436 IF array_upper(isin, 1) IS NOT NULL THEN
1437 FOR i IN 1..array_upper(isin, 1) LOOP
1438 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1439 IF address_street_word_id IS NOT NULL THEN
1440 isin_tokens := isin_tokens + address_street_word_id;
1444 isin_tokens := uniq(sort(isin_tokens));
1446 --RAISE WARNING 'ISIN: %', isin_tokens;
1448 -- Process area matches
1449 location_rank_search := 100;
1450 location_distance := 0;
1451 --RAISE WARNING ' getNearFeatures(%,%,%,%)',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1452 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1454 --RAISE WARNING ' AREA: %',location;
1456 IF location.rank_search < location_rank_search THEN
1457 location_rank_search := location.rank_search;
1458 location_distance := location.distance * 1.5;
1461 IF location.distance < location_distance THEN
1463 -- Add it to the list of search terms
1464 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1465 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1466 address_havelevel[location.rank_address] := true;
1468 IF location.rank_address > parent_place_id_rank THEN
1469 NEW.parent_place_id = location.place_id;
1470 parent_place_id_rank = location.rank_address;
1477 -- try using the isin value to find parent places
1478 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1479 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1480 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1482 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1484 --RAISE WARNING ' ISIN: %',location;
1486 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1487 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1488 address_havelevel[location.rank_address] := true;
1490 IF location.rank_address > parent_place_id_rank THEN
1491 NEW.parent_place_id = location.place_id;
1492 parent_place_id_rank = location.rank_address;
1500 -- for long ways we should add search terms for the entire length
1501 IF st_length(NEW.geometry) > 0.05 THEN
1503 location_rank_search := 100;
1504 location_distance := 0;
1506 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1508 IF location.rank_search < location_rank_search THEN
1509 location_rank_search := location.rank_search;
1510 location_distance := location.distance * 1.5;
1513 IF location.distance < location_distance THEN
1515 -- Add it to the list of search terms
1516 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1517 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1525 -- if we have a name add this to the name search table
1526 IF NEW.name IS NOT NULL THEN
1528 IF NEW.rank_search <= 25 THEN
1529 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1532 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1533 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1536 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1538 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1548 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1554 IF OLD.rank_address < 30 THEN
1556 -- mark everything linked to this place for re-indexing
1557 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1558 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1560 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1562 b := deleteRoad(OLD.partition, OLD.place_id);
1564 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1568 IF OLD.rank_address < 26 THEN
1569 b := deleteLocationArea(OLD.partition, OLD.place_id);
1572 IF OLD.name is not null THEN
1573 b := deleteSearchName(OLD.partition, OLD.place_id);
1576 DELETE FROM place_addressline where place_id = OLD.place_id;
1584 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1590 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1593 UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1595 -- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1602 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1607 existingplacex RECORD;
1608 existinggeometry GEOMETRY;
1609 existingplace_id INTEGER;
1614 IF FALSE and NEW.osm_type = 'R' THEN
1615 RAISE WARNING '-----------------------------------------------------------------------------------';
1616 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1617 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;
1618 RAISE WARNING '%', existingplacex;
1621 -- Just block these - lots and pointless
1622 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1625 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1629 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
1630 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1631 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1632 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1636 -- Patch in additional country names
1637 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1638 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1641 -- Have we already done this place?
1642 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;
1644 -- Get the existing place_id
1645 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;
1647 -- Handle a place changing type by removing the old data
1648 -- My generated 'place' types are causing havok because they overlap with real tags
1649 -- TODO: move them to their own special purpose key/class to avoid collisions
1650 -- IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1651 -- 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');
1654 -- RAISE WARNING 'Existing: %',existing.place_id;
1657 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1658 AND st_area(existing.geometry) > 0.02
1659 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1660 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1662 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1663 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1667 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1669 -- 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
1670 IF existing.osm_type IS NULL
1671 OR existingplacex.osm_type IS NULL
1672 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1673 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1674 OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1675 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1678 -- IF existing.osm_type IS NULL THEN
1679 -- RAISE WARNING 'no existing place';
1681 -- IF existingplacex.osm_type IS NULL THEN
1682 -- RAISE WARNING 'no existing placex %', existingplacex;
1685 -- RAISE WARNING 'delete and replace';
1687 IF existing.osm_type IS NOT NULL THEN
1688 -- 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;
1689 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1692 -- RAISE WARNING 'delete and replace2';
1694 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1695 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1696 street, isin, postcode, country_code, extratags, geometry)
1697 values (NEW.osm_type
1712 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1717 -- Various ways to do the update
1719 -- Debug, what's changed?
1721 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1722 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1724 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1725 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1727 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1728 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1730 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1731 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1733 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1734 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1736 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1737 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1741 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1742 IF existing.geometry::text != NEW.geometry::text
1743 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1744 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1747 -- Get the version of the geometry actually used (in placex table)
1748 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;
1750 -- Performance limit
1751 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1753 -- 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
1754 update placex set indexed_status = 2 where indexed_status = 0 and
1755 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1756 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1757 AND rank_search > existingplacex.rank_search;
1759 update placex set indexed_status = 2 where indexed_status = 0 and
1760 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1761 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1762 AND rank_search > existingplacex.rank_search;
1768 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1769 IF FALSE AND existingplacex.rank_search < 26
1770 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1771 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1772 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1773 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1774 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1775 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1778 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1780 IF st_area(NEW.geometry) < 0.5 THEN
1781 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1782 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1789 -- Anything else has changed - reindex the lot
1790 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1791 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1792 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1793 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1794 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1795 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1797 -- performance, can't take the load of re-indexing a whole country / huge area
1798 IF st_area(NEW.geometry) < 0.5 THEN
1799 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1800 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
1807 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1808 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
1809 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1810 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1811 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1812 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1813 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1814 OR existing.geometry::text != NEW.geometry::text
1819 housenumber = NEW.housenumber,
1820 street = NEW.street,
1822 postcode = NEW.postcode,
1823 country_code = NEW.country_code,
1824 extratags = NEW.extratags,
1825 geometry = NEW.geometry
1826 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1830 housenumber = NEW.housenumber,
1831 street = NEW.street,
1833 postcode = NEW.postcode,
1834 country_code = NEW.country_code,
1835 parent_place_id = null,
1836 extratags = NEW.extratags,
1838 geometry = NEW.geometry
1839 where place_id = existingplacex.place_id;
1841 -- now done as part of insert
1842 -- partition := get_partition(NEW.geometry, existingplacex.country_code);
1843 -- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
1847 -- Abort the add (we modified the existing place instead)
1851 $$ LANGUAGE plpgsql;
1853 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
1860 IF name is null THEN
1864 search := languagepref;
1866 FOR j IN 1..array_upper(search, 1) LOOP
1867 IF name ? search[j] AND trim(name->search[j]) != '' THEN
1868 return trim(name->search[j]);
1875 LANGUAGE plpgsql IMMUTABLE;
1877 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
1880 searchnodes INTEGER[];
1885 searchnodes := '{}';
1886 FOR j IN 1..array_upper(way_ids, 1) LOOP
1888 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
1890 searchnodes := searchnodes | location.nodes;
1894 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
1897 LANGUAGE plpgsql IMMUTABLE;
1899 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id INTEGER) RETURNS TEXT
1910 search := ARRAY['ref'];
1913 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
1916 select rank_address,name,distance,length(name::text) as namelength
1917 from place_addressline join placex on (address_place_id = placex.place_id)
1918 where place_addressline.place_id = for_place_id and rank_address in (5,11)
1919 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
1921 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
1922 FOR j IN 1..array_upper(search, 1) LOOP
1923 FOR k IN 1..array_upper(location.name, 1) LOOP
1924 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
1925 result[(100 - location.rank_address)] := trim(location.name[k].value);
1926 found := location.rank_address;
1933 RETURN array_to_string(result,', ');
1938 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id INTEGER, languagepref TEXT[]) RETURNS TEXT
1950 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
1951 currresult := trim(get_name_by_language(location.name, languagepref));
1952 IF currresult != prevresult AND currresult IS NOT NULL THEN
1953 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
1954 prevresult := currresult;
1958 RETURN array_to_string(result,', ');
1963 DROP TYPE addressline CASCADE;
1964 create type addressline as (
1971 admin_level INTEGER,
1974 rank_address INTEGER,
1978 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id INTEGER) RETURNS setof addressline
1981 for_place_id INTEGER;
1986 countrylocation RECORD;
1987 searchcountrycode varchar(2);
1988 searchhousenumber TEXT;
1989 searchhousename HSTORE;
1990 searchrankaddress INTEGER;
1991 searchpostcode TEXT;
1998 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
1999 WHERE place_id = in_place_id
2000 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2002 IF for_place_id IS NULL THEN
2003 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2004 WHERE place_id = in_place_id
2005 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2008 IF for_place_id IS NULL THEN
2009 select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex
2010 WHERE place_id = in_place_id and rank_address = 30
2011 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2014 IF for_place_id IS NULL THEN
2015 for_place_id := in_place_id;
2016 select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2017 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2020 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2023 hadcountry := false;
2025 select placex.place_id, osm_type, osm_id,
2026 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2027 class, type, admin_level, true as fromarea, true as isaddress,
2028 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2029 0 as distance, country_code
2031 where place_id = for_place_id
2033 --RAISE WARNING '%',location;
2034 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2035 searchcountrycode := location.country_code;
2037 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2038 location.isaddress := FALSE;
2040 IF location.rank_address = 4 AND location.isaddress THEN
2043 IF location.rank_address < 4 AND NOT hadcountry THEN
2044 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2045 IF countryname IS NOT NULL THEN
2046 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2047 RETURN NEXT countrylocation;
2050 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2051 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2052 location.distance)::addressline;
2053 RETURN NEXT countrylocation;
2054 found := location.rank_address;
2058 select placex.place_id, osm_type, osm_id,
2059 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2060 class, type, admin_level, fromarea, isaddress,
2061 CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2062 distance,country_code
2063 from place_addressline join placex on (address_place_id = placex.place_id)
2064 where place_addressline.place_id = for_place_id
2065 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2066 and address_place_id != for_place_id
2067 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2068 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2070 --RAISE WARNING '%',location;
2071 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2072 searchcountrycode := location.country_code;
2074 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2075 location.isaddress := FALSE;
2077 IF location.rank_address = 4 AND location.isaddress THEN
2080 IF location.rank_address < 4 AND NOT hadcountry THEN
2081 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2082 IF countryname IS NOT NULL THEN
2083 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2084 RETURN NEXT countrylocation;
2087 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2088 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2089 location.distance)::addressline;
2090 RETURN NEXT countrylocation;
2091 found := location.rank_address;
2095 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2096 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2097 IF countryname IS NOT NULL THEN
2098 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2099 RETURN NEXT location;
2103 IF searchcountrycode IS NOT NULL THEN
2104 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2105 RETURN NEXT location;
2108 IF searchhousename IS NOT NULL THEN
2109 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2110 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2111 RETURN NEXT location;
2114 IF searchhousenumber IS NOT NULL THEN
2115 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2116 RETURN NEXT location;
2119 IF searchpostcode IS NOT NULL THEN
2120 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2121 RETURN NEXT location;
2129 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
2132 result place_boundingbox;
2133 numfeatures integer;
2135 select * from place_boundingbox into result where place_id = search_place_id;
2136 IF result.place_id IS NULL THEN
2137 -- remove isaddress = true because if there is a matching polygon it always wins
2138 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2139 insert into place_boundingbox select place_id,
2140 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2141 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2142 numfeatures, ST_Area(geometry),
2143 geometry as area from location_area where place_id = search_place_id;
2144 select * from place_boundingbox into result where place_id = search_place_id;
2146 IF result.place_id IS NULL THEN
2148 insert into place_boundingbox select address_place_id,
2149 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2150 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2151 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2152 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2153 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)
2154 where address_place_id = search_place_id
2155 -- and (isaddress = true OR place_id = search_place_id)
2156 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2157 group by address_place_id limit 1;
2158 select * from place_boundingbox into result where place_id = search_place_id;
2165 -- don't do the operation if it would be slow
2166 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
2169 result place_boundingbox;
2170 numfeatures integer;
2173 select * from place_boundingbox into result where place_id = search_place_id;
2174 IF result IS NULL AND rank > 14 THEN
2175 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2176 insert into place_boundingbox select place_id,
2177 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2178 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2179 numfeatures, ST_Area(geometry),
2180 geometry as area from location_area where place_id = search_place_id;
2181 select * from place_boundingbox into result where place_id = search_place_id;
2183 IF result IS NULL THEN
2184 select rank_search from placex where place_id = search_place_id into rank;
2187 insert into place_boundingbox select address_place_id,
2188 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2189 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2190 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2191 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2192 from place_addressline join placex using (place_id)
2193 where address_place_id = search_place_id
2194 and (isaddress = true OR place_id = search_place_id)
2195 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2196 group by address_place_id limit 1;
2197 select * from place_boundingbox into result where place_id = search_place_id;
2205 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2208 result place_boundingbox;
2209 numfeatures integer;
2213 housenumber = place.housenumber,
2214 street = place.street,
2216 postcode = place.postcode,
2217 country_code = place.country_code,
2218 parent_place_id = null
2220 where placex.place_id = search_place_id
2221 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2222 and place.class = placex.class and place.type = placex.type;
2223 update placex set indexed_status = 2 where place_id = search_place_id;
2224 update placex set indexed_status = 0 where place_id = search_place_id;
2230 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2236 ELSEIF rank < 4 THEN
2238 ELSEIF rank < 8 THEN
2240 ELSEIF rank < 12 THEN
2242 ELSEIF rank < 16 THEN
2244 ELSEIF rank = 16 THEN
2246 ELSEIF rank = 17 THEN
2247 RETURN 'Town / Island';
2248 ELSEIF rank = 18 THEN
2249 RETURN 'Village / Hamlet';
2250 ELSEIF rank = 20 THEN
2252 ELSEIF rank = 21 THEN
2253 RETURN 'Postcode Area';
2254 ELSEIF rank = 22 THEN
2255 RETURN 'Croft / Farm / Locality / Islet';
2256 ELSEIF rank = 23 THEN
2257 RETURN 'Postcode Area';
2258 ELSEIF rank = 25 THEN
2259 RETURN 'Postcode Point';
2260 ELSEIF rank = 26 THEN
2261 RETURN 'Street / Major Landmark';
2262 ELSEIF rank = 27 THEN
2263 RETURN 'Minory Street / Path';
2264 ELSEIF rank = 28 THEN
2265 RETURN 'House / Building';
2267 RETURN 'Other: '||rank;
2274 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2280 ELSEIF rank < 2 THEN
2282 ELSEIF rank < 4 THEN
2284 ELSEIF rank = 5 THEN
2286 ELSEIF rank < 8 THEN
2288 ELSEIF rank < 12 THEN
2290 ELSEIF rank < 16 THEN
2292 ELSEIF rank = 16 THEN
2294 ELSEIF rank = 17 THEN
2295 RETURN 'Town / Village / Hamlet';
2296 ELSEIF rank = 20 THEN
2298 ELSEIF rank = 21 THEN
2299 RETURN 'Postcode Area';
2300 ELSEIF rank = 22 THEN
2301 RETURN 'Croft / Farm / Locality / Islet';
2302 ELSEIF rank = 23 THEN
2303 RETURN 'Postcode Area';
2304 ELSEIF rank = 25 THEN
2305 RETURN 'Postcode Point';
2306 ELSEIF rank = 26 THEN
2307 RETURN 'Street / Major Landmark';
2308 ELSEIF rank = 27 THEN
2309 RETURN 'Minory Street / Path';
2310 ELSEIF rank = 28 THEN
2311 RETURN 'House / Building';
2313 RETURN 'Other: '||rank;
2320 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2327 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2328 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2335 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2343 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2345 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2346 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2348 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2356 CREATE AGGREGATE array_agg(INT[])
2363 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2364 in_endnumber INTEGER, interpolationtype TEXT,
2365 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2369 startnumber INTEGER;
2374 numberrange INTEGER;
2375 rangestartnumber INTEGER;
2376 place_centroid GEOMETRY;
2378 parent_place_id INTEGER;
2380 address_street_word_id INTEGER;
2384 IF in_endnumber > in_startnumber THEN
2385 startnumber = in_startnumber;
2386 endnumber = in_endnumber;
2388 startnumber = in_endnumber;
2389 endnumber = in_startnumber;
2392 numberrange := endnumber - startnumber;
2393 rangestartnumber := startnumber;
2395 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2396 startnumber := startnumber + 1;
2399 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2401 ELSE -- everything else assumed to be 'all'
2406 -- Filter out really broken tiger data
2407 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2408 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2409 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2410 ST_length(linegeo)/(numberrange::float/stepsize::float);
2414 place_centroid := ST_Centroid(linegeo);
2415 partition := get_partition(place_centroid, 'us');
2416 parent_place_id := null;
2418 address_street_word_id := get_name_id(make_standard_name(in_street));
2419 IF address_street_word_id IS NOT NULL THEN
2420 FOR location IN SELECT * from getNearestNamedRoadFeature(partition, place_centroid, address_street_word_id) LOOP
2421 parent_place_id := location.place_id;
2425 IF parent_place_id IS NULL THEN
2426 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(partition, linegeo) LOOP
2427 parent_place_id := location.place_id;
2431 IF parent_place_id IS NULL THEN
2432 FOR location IN SELECT place_id FROM getNearestRoadFeature(partition, place_centroid) LOOP
2433 parent_place_id := location.place_id;
2438 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2439 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2440 values (nextval('seq_place'), partition, parent_place_id, housenum, in_postcode,
2441 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2442 newpoints := newpoints + 1;
2450 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2451 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2456 place_centroid GEOMETRY;
2458 parent_place_id INTEGER;
2460 address_street_word_id INTEGER;
2464 place_centroid := ST_Centroid(pointgeo);
2465 partition := get_partition(place_centroid, in_countrycode);
2466 parent_place_id := null;
2468 address_street_word_id := get_name_id(make_standard_name(in_street));
2469 IF address_street_word_id IS NOT NULL THEN
2470 FOR location IN SELECT * from getNearestNamedRoadFeature(partition, place_centroid, address_street_word_id) LOOP
2471 parent_place_id := location.place_id;
2475 IF parent_place_id IS NULL THEN
2476 FOR location IN SELECT place_id FROM getNearestRoadFeature(partition, place_centroid) LOOP
2477 parent_place_id := location.place_id;
2482 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2483 values (nextval('seq_place'), partition, parent_place_id, in_housenumber, in_postcode, place_centroid);
2484 newpoints := newpoints + 1;