1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
56 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
57 NEWgeometry := ST_buffer(NEWgeometry,0);
58 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
62 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
72 -- RAISE WARNING '%',osmid;
77 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
78 NEWgeometry := ST_buffer(NEWgeometry,0);
79 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
83 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
86 LANGUAGE plpgsql IMMUTABLE;
88 CREATE OR REPLACE FUNCTION geometry_index(place geometry,indexed BOOLEAN,name keyvalue[]) RETURNS INTEGER
91 IF indexed THEN RETURN NULL; END IF;
92 IF name is null THEN RETURN NULL; END IF;
93 RETURN geometry_sector(place);
96 LANGUAGE plpgsql IMMUTABLE;
98 CREATE OR REPLACE FUNCTION geometry_index(sector integer, indexed BOOLEAN, name keyvalue[]) RETURNS INTEGER
101 IF indexed THEN RETURN NULL; END IF;
102 IF name is null THEN RETURN NULL; END IF;
106 LANGUAGE plpgsql IMMUTABLE;
108 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
109 AS '/home/brian/nominatim/live/osm2pgsql/gazetteer/gazetteer.so', 'transliteration'
110 LANGUAGE c IMMUTABLE STRICT;
112 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
113 AS '/home/brian/nominatim/live/osm2pgsql/gazetteer/gazetteer.so', 'gettokenstring'
114 LANGUAGE c IMMUTABLE STRICT;
116 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
121 o := gettokenstring(transliteration(name));
122 RETURN trim(substr(o,1,length(o)));
125 LANGUAGE 'plpgsql' IMMUTABLE;
127 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
132 return_word_id INTEGER;
134 lookup_token := trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
168 return_word_id INTEGER;
170 lookup_token := ' '||trim(lookup_word);
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := ' '||trim(lookup_word);
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
190 IF return_word_id IS NULL THEN
191 return_word_id := nextval('seq_word');
192 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
194 RETURN return_word_id;
199 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
204 return_word_id INTEGER;
206 lookup_token := lookup_class||'='||lookup_type;
207 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
208 IF return_word_id IS NULL THEN
209 return_word_id := nextval('seq_word');
210 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
212 RETURN return_word_id;
217 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
222 return_word_id INTEGER;
224 lookup_token := lookup_class||'='||lookup_type;
225 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
226 RETURN return_word_id;
231 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
236 return_word_id INTEGER;
238 lookup_token := ' '||trim(lookup_word);
239 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
240 IF return_word_id IS NULL THEN
241 return_word_id := nextval('seq_word');
242 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null, op);
244 RETURN return_word_id;
249 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
254 nospace_lookup_token TEXT;
255 return_word_id INTEGER;
257 lookup_token := ' '||trim(lookup_word);
258 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
259 IF return_word_id IS NULL THEN
260 return_word_id := nextval('seq_word');
261 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
262 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
263 -- IF ' '||nospace_lookup_token != lookup_token THEN
264 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
267 RETURN return_word_id;
272 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
277 RETURN getorcreate_name_id(lookup_word, '');
282 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
287 return_word_id INTEGER;
289 lookup_token := trim(lookup_word);
290 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
291 RETURN return_word_id;
294 LANGUAGE plpgsql IMMUTABLE;
296 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
301 return_word_id INTEGER;
303 lookup_token := ' '||trim(lookup_word);
304 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
305 RETURN return_word_id;
308 LANGUAGE plpgsql IMMUTABLE;
310 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
317 IF array_upper(a, 1) IS NULL THEN
320 IF array_upper(b, 1) IS NULL THEN
324 FOR i IN 1..array_upper(b, 1) LOOP
325 IF NOT (ARRAY[b[i]] && r) THEN
332 LANGUAGE plpgsql IMMUTABLE;
334 CREATE OR REPLACE FUNCTION add_keywords(a keyvalue[], b keyvalue[]) RETURNS keyvalue[]
342 IF array_upper(a, 1) IS NULL THEN
345 IF array_upper(b, 1) IS NULL THEN
349 FOR i IN 1..array_upper(b, 1) LOOP
351 FOR j IN 1..array_upper(a, 1) LOOP
352 IF (a[j].key = b[i].key) THEN
363 LANGUAGE plpgsql IMMUTABLE;
365 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
375 result := '{}'::INTEGER[];
377 FOR item IN SELECT (each(src)).* LOOP
379 s := make_standard_name(item.value);
381 w := getorcreate_name_id(s, item.value);
382 result := result | w;
384 words := string_to_array(s, ' ');
385 IF array_upper(words, 1) IS NOT NULL THEN
386 FOR j IN 1..array_upper(words, 1) LOOP
387 IF (words[j] != '') THEN
388 w = getorcreate_word_id(words[j]);
389 IF NOT (ARRAY[w] && result) THEN
390 result := result | w;
396 words := regexp_split_to_array(item.value, E'[,;()]');
397 IF array_upper(words, 1) != 1 THEN
398 FOR j IN 1..array_upper(words, 1) LOOP
399 s := make_standard_name(words[j]);
401 w := getorcreate_word_id(s);
402 IF NOT (ARRAY[w] && result) THEN
403 result := result | w;
409 s := regexp_replace(item.value, '市$', '');
410 IF s != item.value THEN
411 s := make_standard_name(s);
413 w := getorcreate_name_id(s, item.value);
414 IF NOT (ARRAY[w] && result) THEN
415 result := result | w;
425 LANGUAGE plpgsql IMMUTABLE;
427 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
437 result := '{}'::INTEGER[];
439 s := make_standard_name(src);
440 w := getorcreate_name_id(s);
442 IF NOT (ARRAY[w] && result) THEN
443 result := result || w;
446 words := string_to_array(s, ' ');
447 IF array_upper(words, 1) IS NOT NULL THEN
448 FOR j IN 1..array_upper(words, 1) LOOP
449 IF (words[j] != '') THEN
450 w = getorcreate_word_id(words[j]);
451 IF NOT (ARRAY[w] && result) THEN
452 result := result || w;
461 LANGUAGE plpgsql IMMUTABLE;
463 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
470 IF (wordscores is null OR words is null) THEN
475 FOR idxword in 1 .. array_upper(words, 1) LOOP
476 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
477 IF wordscores[idxscores].word = words[idxword] THEN
478 result := result + wordscores[idxscores].score;
486 LANGUAGE plpgsql IMMUTABLE;
488 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
491 place_centre GEOMETRY;
494 place_centre := ST_Centroid(place);
496 -- Try for a OSM polygon first
497 FOR nearcountry IN select country_code from location_area where st_contains(area, place_centre) limit 1
499 RETURN nearcountry.country_code;
502 -- Try for an OSM polygon first, grid is faster
503 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
505 RETURN nearcountry.country_code;
508 -- Natural earth data (first fallback)
509 -- FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
511 -- RETURN nearcountry.country_code;
514 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
515 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
517 RETURN nearcountry.country_code;
520 -- Still not in a country - try nearest within ~12 miles of a country
521 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
522 order by st_distance(geometry, place) limit 1
524 RETURN nearcountry.country_code;
530 LANGUAGE plpgsql IMMUTABLE;
532 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
537 FOR nearcountry IN select distinct country_default_language_code from country where country_code = search_country_code limit 1
539 RETURN lower(nearcountry.country_default_language_code);
544 LANGUAGE plpgsql IMMUTABLE;
546 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
550 DELETE FROM location_area where place_id = OLD_place_id;
551 -- TODO:location_area
557 CREATE OR REPLACE FUNCTION add_location(
559 place_country_code varchar(2),
562 rank_address INTEGER,
569 country_code VARCHAR(2);
582 -- Allocate all tokens ids - prevents multi-processor race condition later on at cost of slowing down import
583 keywords := make_keywords(name);
585 -- 26 = street/highway
586 IF rank_search <= 26 THEN
587 IF place_country_code IS NULL THEN
588 country_code := get_country_code(geometry);
590 country_code := lower(place_country_code);
593 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
597 xmin := floor(st_xmin(geometry));
598 xmax := ceil(st_xmax(geometry));
599 ymin := floor(st_ymin(geometry));
600 ymax := ceil(st_ymax(geometry));
602 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
603 INSERT INTO location_area values (place_id, country_code, name, keywords,
604 rank_search, rank_address, false, ST_Centroid(geometry), geometry);
606 FOR lon IN xmin..(xmax-1) LOOP
607 FOR lat IN ymin..(ymax-1) LOOP
608 secgeo := st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326));
609 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
610 INSERT INTO location_area values (place_id, country_code, name, keywords,
611 rank_search, rank_address, false, ST_Centroid(geometry),
612 st_intersection(geometry, ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326))
622 IF rank_search = 14 THEN
624 ELSEIF rank_search = 15 THEN
626 ELSEIF rank_search = 16 THEN
628 ELSEIF rank_search = 17 THEN
630 ELSEIF rank_search = 25 THEN
632 ELSEIF rank_search = 26 THEN
636 secgeo := ST_Buffer(geometry, diameter);
637 INSERT INTO location_area values (place_id, country_code, name, keywords,
638 rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
642 INSERT INTO location_point values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
647 IF rank_search < 26 THEN
648 INSERT INTO location_point_26 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
649 IF rank_search < 25 THEN
650 INSERT INTO location_point_25 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
651 IF rank_search < 24 THEN
652 INSERT INTO location_point_24 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
653 IF rank_search < 23 THEN
654 INSERT INTO location_point_23 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
655 IF rank_search < 22 THEN
656 INSERT INTO location_point_22 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
657 IF rank_search < 21 THEN
658 INSERT INTO location_point_21 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
659 IF rank_search < 20 THEN
660 INSERT INTO location_point_20 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
661 IF rank_search < 19 THEN
662 INSERT INTO location_point_19 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
663 IF rank_search < 18 THEN
664 INSERT INTO location_point_18 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
665 IF rank_search < 17 THEN
666 INSERT INTO location_point_17 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
667 IF rank_search < 16 THEN
668 INSERT INTO location_point_16 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
669 IF rank_search < 15 THEN
670 INSERT INTO location_point_15 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
671 IF rank_search < 14 THEN
672 INSERT INTO location_point_14 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
673 IF rank_search < 13 THEN
674 INSERT INTO location_point_13 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
675 IF rank_search < 12 THEN
676 INSERT INTO location_point_12 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
677 IF rank_search < 11 THEN
678 INSERT INTO location_point_11 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
679 IF rank_search < 10 THEN
680 INSERT INTO location_point_10 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
681 IF rank_search < 9 THEN
682 INSERT INTO location_point_9 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
683 IF rank_search < 8 THEN
684 INSERT INTO location_point_8 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
685 IF rank_search < 7 THEN
686 INSERT INTO location_point_7 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
687 IF rank_search < 6 THEN
688 INSERT INTO location_point_6 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
689 IF rank_search < 5 THEN
690 INSERT INTO location_point_5 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
691 IF rank_search < 4 THEN
692 INSERT INTO location_point_4 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
693 IF rank_search < 3 THEN
694 INSERT INTO location_point_3 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
695 IF rank_search < 2 THEN
696 INSERT INTO location_point_2 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
697 IF rank_search < 1 THEN
698 INSERT INTO location_point_1 values (place_id,country_code,name,keywords,rank_search,rank_address,isarea,ST_Centroid(geometry));
699 END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;
700 END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;END IF;
701 END IF;END IF;END IF;END IF;END IF;END IF;END IF;
710 CREATE OR REPLACE FUNCTION update_location(
712 place_country_code varchar(2),
715 rank_address INTEGER,
723 b := delete_location(place_id);
724 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
729 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
740 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
741 FOR childplace IN select * from search_name,place_addressline
742 where address_place_id = parent_place_id
743 and search_name.place_id = place_addressline.place_id
745 delete from search_name where place_id = childplace.place_id;
746 childplace.nameaddress_vector := uniq(sort_asc(childplace.nameaddress_vector + to_add));
747 IF childplace.place_id = parent_place_id THEN
748 childplace.name_vector := uniq(sort_asc(childplace.name_vector + to_add));
750 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
751 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
752 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
760 CREATE OR REPLACE FUNCTION update_location_nameonly(OLD_place_id BIGINT, name keyvalue[]) RETURNS BOOLEAN
763 newkeywords INTEGER[];
764 addedkeywords INTEGER[];
765 removedkeywords INTEGER[];
769 newkeywords := make_keywords(name);
770 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
771 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
772 where place_id = OLD_place_id into addedkeywords, removedkeywords;
774 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
776 IF #removedkeywords > 0 THEN
777 -- abort due to tokens removed
781 IF #addedkeywords > 0 THEN
782 -- short circuit - no changes
786 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
787 UPDATE location_point set keywords = newkeywords where place_id = OLD_place_id;
788 UPDATE location_point_0 set keywords = newkeywords where place_id = OLD_place_id;
789 UPDATE location_point_1 set keywords = newkeywords where place_id = OLD_place_id;
790 UPDATE location_point_2 set keywords = newkeywords where place_id = OLD_place_id;
791 UPDATE location_point_3 set keywords = newkeywords where place_id = OLD_place_id;
792 UPDATE location_point_4 set keywords = newkeywords where place_id = OLD_place_id;
793 UPDATE location_point_5 set keywords = newkeywords where place_id = OLD_place_id;
794 UPDATE location_point_6 set keywords = newkeywords where place_id = OLD_place_id;
795 UPDATE location_point_7 set keywords = newkeywords where place_id = OLD_place_id;
796 UPDATE location_point_8 set keywords = newkeywords where place_id = OLD_place_id;
797 UPDATE location_point_9 set keywords = newkeywords where place_id = OLD_place_id;
798 UPDATE location_point_10 set keywords = newkeywords where place_id = OLD_place_id;
799 UPDATE location_point_11 set keywords = newkeywords where place_id = OLD_place_id;
800 UPDATE location_point_12 set keywords = newkeywords where place_id = OLD_place_id;
801 UPDATE location_point_13 set keywords = newkeywords where place_id = OLD_place_id;
802 UPDATE location_point_14 set keywords = newkeywords where place_id = OLD_place_id;
803 UPDATE location_point_15 set keywords = newkeywords where place_id = OLD_place_id;
804 UPDATE location_point_16 set keywords = newkeywords where place_id = OLD_place_id;
805 UPDATE location_point_17 set keywords = newkeywords where place_id = OLD_place_id;
806 UPDATE location_point_18 set keywords = newkeywords where place_id = OLD_place_id;
807 UPDATE location_point_19 set keywords = newkeywords where place_id = OLD_place_id;
808 UPDATE location_point_20 set keywords = newkeywords where place_id = OLD_place_id;
809 UPDATE location_point_21 set keywords = newkeywords where place_id = OLD_place_id;
810 UPDATE location_point_22 set keywords = newkeywords where place_id = OLD_place_id;
811 UPDATE location_point_23 set keywords = newkeywords where place_id = OLD_place_id;
812 UPDATE location_point_24 set keywords = newkeywords where place_id = OLD_place_id;
813 UPDATE location_point_25 set keywords = newkeywords where place_id = OLD_place_id;
814 UPDATE location_point_26 set keywords = newkeywords where place_id = OLD_place_id;
816 RETURN search_name_add_words(OLD_place_id, addedkeywords);
822 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
834 orginalstartnumber INTEGER;
835 originalnumberrange INTEGER;
838 search_place_id INTEGER;
840 havefirstpoint BOOLEAN;
844 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
846 select nodes from planet_osm_ways where id = wayid INTO waynodes;
847 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
848 IF array_upper(waynodes, 1) IS NOT NULL THEN
850 havefirstpoint := false;
852 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
854 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::bigint and type = 'house' INTO search_place_id;
855 IF search_place_id IS NULL THEN
856 -- null record of right type
857 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::bigint and type = 'house' limit 1 INTO nextnode;
858 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
860 select * from placex where place_id = search_place_id INTO nextnode;
863 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
865 IF havefirstpoint THEN
867 -- add point to the line string
868 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
869 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
871 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 THEN
873 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
875 IF startnumber != endnumber THEN
877 linestr := linestr || ')';
878 --RAISE WARNING 'linestr %',linestr;
879 linegeo := ST_GeomFromText(linestr,4326);
880 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
881 IF (startnumber > endnumber) THEN
882 housenum := endnumber;
883 endnumber := startnumber;
884 startnumber := housenum;
885 linegeo := ST_Reverse(linegeo);
887 orginalstartnumber := startnumber;
888 originalnumberrange := endnumber - startnumber;
890 -- Too much broken data worldwide for this test to be worth using
891 -- IF originalnumberrange > 500 THEN
892 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
895 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
896 startnumber := startnumber + 1;
899 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
900 startnumber := startnumber + 2;
902 ELSE -- everything else assumed to be 'all'
903 startnumber := startnumber + 1;
907 endnumber := endnumber - 1;
908 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
909 FOR housenum IN startnumber..endnumber BY stepsize LOOP
910 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
911 -- ideally postcodes should move up to the way
912 insert into placex values (null,'N',prevnode.osm_id,prevnode.class,prevnode.type,NULL,prevnode.admin_level,housenum,prevnode.street,prevnode.isin,null,prevnode.country_code,prevnode.street_place_id,prevnode.rank_address,prevnode.rank_search,false,ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
913 newpoints := newpoints + 1;
914 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
917 havefirstpoint := false;
921 IF NOT havefirstpoint THEN
922 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
923 IF startnumber IS NOT NULL AND startnumber > 0 THEN
924 havefirstpoint := true;
925 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
926 prevnode := nextnode;
928 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
934 --RAISE WARNING 'interpolation points % ',newpoints;
941 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
947 country_code VARCHAR(2);
950 -- RAISE WARNING '%',NEW.osm_id;
951 -- RAISE WARNING '%',NEW.osm_id;
954 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
957 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
961 -- RAISE WARNING '%',NEW.osm_id;
962 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
963 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
967 IF NEW.osm_type = 'R' THEN
968 -- invalid multipolygons can crash postgis, don't even bother to try!
971 NEW.geometry := ST_buffer(NEW.geometry,0);
972 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
973 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
978 NEW.place_id := nextval('seq_place');
979 NEW.indexed := false;
980 NEW.country_code := lower(NEW.country_code);
981 NEW.geometry_sector := geometry_sector(NEW.geometry);
983 IF NEW.admin_level > 15 THEN
984 NEW.admin_level := 15;
987 IF NEW.housenumber IS NOT NULL THEN
988 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
991 IF NEW.osm_type = 'X' THEN
992 -- E'X'ternal records should already be in the right format so do nothing
994 NEW.rank_search := 30;
995 NEW.rank_address := NEW.rank_search;
997 -- By doing in postgres we have the country available to us - currently only used for postcode
998 IF NEW.class = 'place' THEN
999 IF NEW.type in ('continent') THEN
1000 NEW.rank_search := 2;
1001 NEW.rank_address := NEW.rank_search;
1002 ELSEIF NEW.type in ('sea') THEN
1003 NEW.rank_search := 2;
1004 NEW.rank_address := 0;
1005 ELSEIF NEW.type in ('country') THEN
1006 NEW.rank_search := 4;
1007 NEW.rank_address := NEW.rank_search;
1008 ELSEIF NEW.type in ('state') THEN
1009 NEW.rank_search := 8;
1010 NEW.rank_address := NEW.rank_search;
1011 ELSEIF NEW.type in ('region') THEN
1012 NEW.rank_search := 10;
1013 NEW.rank_address := NEW.rank_search;
1014 ELSEIF NEW.type in ('county') THEN
1015 NEW.rank_search := 12;
1016 NEW.rank_address := NEW.rank_search;
1017 ELSEIF NEW.type in ('city') THEN
1018 NEW.rank_search := 16;
1019 NEW.rank_address := NEW.rank_search;
1020 ELSEIF NEW.type in ('island') THEN
1021 NEW.rank_search := 17;
1022 NEW.rank_address := 0;
1023 ELSEIF NEW.type in ('town') THEN
1024 NEW.rank_search := 17;
1025 NEW.rank_address := NEW.rank_search;
1026 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1027 NEW.rank_search := 18;
1028 NEW.rank_address := 17;
1029 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1030 NEW.rank_search := 18;
1031 NEW.rank_address := 17;
1032 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1033 NEW.rank_search := 17;
1034 NEW.rank_address := 18;
1035 ELSEIF NEW.type in ('moor') THEN
1036 NEW.rank_search := 17;
1037 NEW.rank_address := 0;
1038 ELSEIF NEW.type in ('national_park') THEN
1039 NEW.rank_search := 18;
1040 NEW.rank_address := 18;
1041 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1042 NEW.rank_search := 20;
1043 NEW.rank_address := NEW.rank_search;
1044 ELSEIF NEW.type in ('farm','locality','islet') THEN
1045 NEW.rank_search := 20;
1046 NEW.rank_address := 0;
1047 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1048 NEW.rank_search := 22;
1049 NEW.rank_address := 22;
1050 ELSEIF NEW.type in ('postcode') THEN
1052 -- Postcode processing is very country dependant
1053 IF NEW.country_code IS NULL THEN
1054 NEW.country_code := get_country_code(NEW.geometry);
1057 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1059 IF NEW.country_code = 'gb' THEN
1061 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1062 NEW.rank_search := 25;
1063 NEW.rank_address := 5;
1064 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1065 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1066 NEW.rank_search := 23;
1067 NEW.rank_address := 5;
1068 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1069 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1070 NEW.rank_search := 21;
1071 NEW.rank_address := 5;
1072 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1075 ELSEIF NEW.country_code = 'de' THEN
1077 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1078 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1079 NEW.rank_search := 21;
1080 NEW.rank_address := 11;
1084 -- Guess at the postcode format and coverage (!)
1085 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1086 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1087 NEW.rank_search := 21;
1088 NEW.rank_address := 11;
1090 -- Does it look splitable into and area and local code?
1091 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1093 IF postcode IS NOT NULL THEN
1095 -- TODO: insert new line into location instead
1096 --result := add_location(NEW.place_id,NEW.country_code,ARRAY[ROW('ref',postcode)::keyvalue],21,11,NEW.geometry);
1098 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1099 NEW.rank_search := 25;
1100 NEW.rank_address := 11;
1101 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1102 NEW.name := ARRAY[ROW('ref',NEW.postcode)::keyvalue];
1103 NEW.rank_search := 21;
1104 NEW.rank_address := 11;
1109 ELSEIF NEW.type in ('airport','street') THEN
1110 NEW.rank_search := 26;
1111 NEW.rank_address := NEW.rank_search;
1112 ELSEIF NEW.type in ('house','building') THEN
1113 NEW.rank_search := 28;
1114 NEW.rank_address := NEW.rank_search;
1115 ELSEIF NEW.type in ('houses') THEN
1116 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1117 -- insert new point into place for each derived building
1118 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1121 ELSEIF NEW.class = 'boundary' THEN
1122 IF NEW.country_code is null THEN
1123 NEW.country_code := get_country_code(NEW.geometry);
1125 NEW.rank_search := NEW.admin_level * 2;
1126 NEW.rank_address := NEW.rank_search;
1127 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1128 NEW.rank_search := 22;
1129 NEW.rank_address := NEW.rank_search;
1130 -- any feature more than 5 square miles is probably worth indexing
1131 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1132 NEW.rank_search := 22;
1133 NEW.rank_address := NEW.rank_search;
1134 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1135 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1137 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1139 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1141 ELSEIF NEW.class = 'waterway' THEN
1142 NEW.rank_address := 17;
1143 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
1144 NEW.rank_search := 27;
1145 NEW.rank_address := NEW.rank_search;
1146 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1147 NEW.rank_search := 26;
1148 NEW.rank_address := NEW.rank_search;
1149 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1150 NEW.rank_search := 4;
1151 NEW.rank_address := NEW.rank_search;
1152 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1154 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1155 NEW.rank_search := 18;
1156 NEW.rank_address := 0;
1161 IF NEW.rank_search > 30 THEN
1162 NEW.rank_search := 30;
1165 IF NEW.rank_address > 30 THEN
1166 NEW.rank_address := 30;
1169 -- Block import below rank 22
1170 -- IF NEW.rank_search > 22 THEN
1174 IF array_upper(NEW.name, 1) is not null THEN
1175 result := add_location(NEW.place_id,NEW.country_code,NEW.name,NEW.rank_search,NEW.rank_address,NEW.geometry);
1179 -- The following is not needed until doing diff updates, and slows the main index process down
1181 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1182 -- Performance: We just can't handle re-indexing for country level changes
1183 IF st_area(NEW.geometry) < 1 THEN
1184 -- mark items within the geometry for re-indexing
1185 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1186 -- work around bug in postgis
1187 update placex set indexed = false where indexed and (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1188 AND rank_search > NEW.rank_search and ST_geometrytype(placex.geometry) = 'ST_Point';
1189 update placex set indexed = false where indexed and (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1190 AND rank_search > NEW.rank_search and ST_geometrytype(placex.geometry) != 'ST_Point';
1193 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1195 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1196 IF NEW.type='postcode' THEN
1198 ELSEIF NEW.rank_search < 16 THEN
1200 ELSEIF NEW.rank_search < 18 THEN
1202 ELSEIF NEW.rank_search < 20 THEN
1204 ELSEIF NEW.rank_search = 21 THEN
1206 ELSEIF NEW.rank_search < 24 THEN
1208 ELSEIF NEW.rank_search < 26 THEN
1209 diameter := 0.002; -- 100 to 200 meters
1210 ELSEIF NEW.rank_search < 28 THEN
1211 diameter := 0.001; -- 50 to 100 meters
1213 IF diameter > 0 THEN
1214 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1215 update placex set indexed = false where indexed and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1220 -- IF NEW.rank_search < 26 THEN
1221 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1230 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1235 place_centroid GEOMETRY;
1236 place_geometry_text TEXT;
1238 search_maxdistance FLOAT[];
1239 search_mindistance FLOAT[];
1240 address_havelevel BOOLEAN[];
1241 -- search_scores wordscore[];
1242 -- search_scores_pos INTEGER;
1243 search_country_code_conflict BOOLEAN;
1249 search_diameter FLOAT;
1250 search_prevdiameter FLOAT;
1251 search_maxrank INTEGER;
1252 address_maxrank INTEGER;
1253 address_street_word_id INTEGER;
1254 street_place_id_count INTEGER;
1258 bPointCountryCode BOOLEAN;
1260 name_vector INTEGER[];
1261 nameaddress_vector INTEGER[];
1267 -- RAISE WARNING '%',NEW.place_id;
1268 --RAISE WARNING '%', NEW;
1270 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1271 -- Silently do nothing
1275 NEW.country_code := lower(NEW.country_code);
1277 IF NEW.indexed and NOT OLD.indexed THEN
1279 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1280 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1284 --RAISE WARNING 'PROCESSING: % %', NEW.place_id, NEW.name;
1286 search_country_code_conflict := false;
1288 DELETE FROM search_name WHERE place_id = NEW.place_id;
1289 --RAISE WARNING 'x1';
1290 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1291 --RAISE WARNING 'x2';
1292 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1294 -- Adding ourselves to the list simplifies address calculations later
1295 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1296 --RAISE WARNING 'x3';
1298 -- What level are we searching from
1299 search_maxrank := NEW.rank_search;
1301 -- Default max/min distances to look for a location
1303 search_maxdistance[i] := 1;
1304 search_mindistance[i] := 0.0;
1305 address_havelevel[i] := false;
1307 -- Minimum size to search, can be larger but don't let it shink below this
1308 search_mindistance[14] := 0.2;
1309 search_mindistance[15] := 0.1;
1310 search_mindistance[16] := 0.05;
1311 search_mindistance[17] := 0.03;
1312 search_mindistance[18] := 0.015;
1313 search_mindistance[19] := 0.008;
1314 search_mindistance[20] := 0.006;
1315 search_mindistance[21] := 0.004;
1316 search_mindistance[22] := 0.003;
1317 search_mindistance[23] := 0.002;
1318 search_mindistance[24] := 0.002;
1319 search_mindistance[25] := 0.001;
1320 search_mindistance[26] := 0.001;
1322 search_maxdistance[14] := 1;
1323 search_maxdistance[15] := 0.5;
1324 search_maxdistance[16] := 0.15;
1325 search_maxdistance[17] := 0.05;
1326 search_maxdistance[18] := 0.02;
1327 search_maxdistance[19] := 0.02;
1328 search_maxdistance[20] := 0.02;
1329 search_maxdistance[21] := 0.02;
1330 search_maxdistance[22] := 0.02;
1331 search_maxdistance[23] := 0.02;
1332 search_maxdistance[24] := 0.02;
1333 search_maxdistance[25] := 0.02;
1334 search_maxdistance[26] := 0.02;
1336 -- Speed up searches - just use the centroid of the feature
1337 -- cheaper but less acurate
1338 place_centroid := ST_Centroid(NEW.geometry);
1339 place_geometry_text := 'ST_GeomFromText('''||ST_AsText(NEW.geometry)||''','||ST_SRID(NEW.geometry)||')';
1341 -- copy the building number to the name
1342 -- done here rather than on insert to avoid initial indexing
1343 -- TODO: This might be a silly thing to do
1344 --IF (NEW.name IS NULL OR array_upper(NEW.name,1) IS NULL) AND NEW.housenumber IS NOT NULL THEN
1345 -- NEW.name := ARRAY[ROW('ref',NEW.housenumber)::keyvalue];
1348 --Temp hack to prevent need to re-index
1349 IF NEW.name::text = '{"(ref,'||NEW.housenumber||')"}' THEN
1353 --IF (NEW.name IS NULL OR array_upper(NEW.name,1) IS NULL) AND NEW.type IS NOT NULL THEN
1354 -- NEW.name := ARRAY[ROW('type',NEW.type)::keyvalue];
1357 -- Initialise the name and address vectors using our name
1358 name_vector := make_keywords(NEW.name);
1359 nameaddress_vector := name_vector;
1361 -- some tag combinations add a special id for search
1362 tagpairid := get_tagpair(NEW.class,NEW.type);
1363 IF tagpairid IS NOT NULL THEN
1364 name_vector := name_vector + tagpairid;
1367 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1369 -- For low level elements we inherit from our parent road
1370 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1372 --RAISE WARNING 'finding street for %', NEW;
1374 NEW.street_place_id := null;
1376 -- to do that we have to find our parent road
1377 -- Copy data from linked items (points on ways, addr:street links, relations)
1378 -- Note that addr:street links can only be indexed once the street itself is indexed
1379 IF NEW.street_place_id IS NULL AND NEW.osm_type = 'N' THEN
1381 -- Is this node part of a relation?
1382 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1384 -- At the moment we only process one type of relation - associatedStreet
1385 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1386 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1387 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1388 --RAISE WARNING 'node in relation %',relation;
1389 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1390 and rank_search = 26 INTO NEW.street_place_id;
1396 --RAISE WARNING 'x1';
1397 -- Is this node part of a way?
1398 FOR location IN select * from placex where osm_type = 'W'
1399 and osm_id in (select id from planet_osm_ways where nodes && ARRAY[NEW.osm_id::integer])
1401 --RAISE WARNING '%', location;
1402 -- Way IS a road then we are on it - that must be our road
1403 IF location.rank_search = 26 AND NEW.street_place_id IS NULL THEN
1404 --RAISE WARNING 'node in way that is a street %',location;
1405 NEW.street_place_id := location.place_id;
1408 -- Is the WAY part of a relation
1409 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1411 -- At the moment we only process one type of relation - associatedStreet
1412 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1413 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1414 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1415 --RAISE WARNING 'node in way that is in a relation %',relation;
1416 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1417 and rank_search = 26 INTO NEW.street_place_id;
1423 -- If the way contains an explicit name of a street copy it
1424 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1425 --RAISE WARNING 'node in way that has a streetname %',location;
1426 NEW.street := location.street;
1429 -- If this way is a street interpolation line then it is probably as good as we are going to get
1430 IF NEW.street_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1431 -- Try and find a way that is close roughly parellel to this line
1432 FOR relation IN SELECT place_id FROM placex
1433 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1434 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1435 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1436 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1438 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1439 NEW.street_place_id := relation.place_id;
1447 --RAISE WARNING 'x2';
1449 IF NEW.street_place_id IS NULL AND NEW.osm_type = 'W' THEN
1450 -- Is this way part of a relation?
1451 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1453 -- At the moment we only process one type of relation - associatedStreet
1454 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1455 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1456 IF NEW.street_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1457 --RAISE WARNING 'way that is in a relation %',relation;
1458 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1459 and rank_search = 26 INTO NEW.street_place_id;
1466 --RAISE WARNING 'x3';
1468 IF NEW.street_place_id IS NULL AND NEW.street IS NOT NULL THEN
1469 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1470 --RAISE WARNING 'street: % %', NEW.street, address_street_word_id;
1471 IF address_street_word_id IS NOT NULL THEN
1472 FOR location IN SELECT place_id,ST_distance(NEW.geometry, search_name.centroid) as distance
1473 FROM search_name WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1474 AND ST_DWithin(NEW.geometry, search_name.centroid, 0.01) and search_rank between 22 and 27
1475 ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1477 --RAISE WARNING 'streetname found nearby %',location;
1478 NEW.street_place_id := location.place_id;
1481 -- Failed, fall back to nearest - don't just stop
1482 IF NEW.street_place_id IS NULL THEN
1483 --RAISE WARNING 'unable to find streetname nearby % %',NEW.street,address_street_word_id;
1488 --RAISE WARNING 'x4';
1491 IF NEW.street_place_id IS NULL THEN
1492 FOR location IN SELECT place_id
1494 WHERE ST_Contains(area, place_centroid) and location_area.rank_search = 26
1495 ORDER BY ST_Distance(place_centroid, centroid) ASC limit 1
1497 search_diameter := 0.00005;
1498 WHILE NEW.street_place_id IS NULL AND search_diameter < 0.1 LOOP
1499 --RAISE WARNING '% %', search_diameter,ST_AsText(ST_Centroid(NEW.geometry));
1500 FOR location IN SELECT place_id FROM placex
1501 WHERE ST_DWithin(place_centroid, placex.geometry, search_diameter) and rank_search between 22 and 27
1502 ORDER BY ST_distance(NEW.geometry, placex.geometry) ASC limit 1
1505 --RAISE WARNING 'using nearest street,% % %',search_diameter,NEW.street,location;
1506 NEW.street_place_id := location.place_id;
1510 --RAISE WARNING 'x6 %',NEW.street_place_id;
1512 -- If we didn't find any road fallback to standard method
1513 IF NEW.street_place_id IS NOT NULL THEN
1515 -- Some unnamed roads won't have been indexed, index now if needed
1516 select count(*) from place_addressline where place_id = NEW.street_place_id INTO street_place_id_count;
1517 IF street_place_id_count = 0 THEN
1518 UPDATE placex set indexed = true where indexed = false and place_id = NEW.street_place_id;
1521 -- Add the street to the address as zero distance to force to front of list
1522 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.street_place_id, true, true, 0, 26);
1523 address_havelevel[26] := true;
1525 -- Import address details from parent, reclculating distance in process
1526 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
1527 from place_addressline as x join placex on (address_place_id = placex.place_id)
1528 where x.place_id = NEW.street_place_id and x.address_place_id != NEW.street_place_id;
1530 -- Get the details of the parent road
1531 select * from search_name where place_id = NEW.street_place_id INTO location;
1532 NEW.country_code := location.country_code;
1534 --RAISE WARNING '%', NEW.name;
1535 -- If there is no name it isn't searchable, don't bother to create a search record
1536 IF NEW.name is NULL THEN
1540 -- Merge address from parent
1541 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1543 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1544 -- Just be happy with inheriting from parent road only
1545 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_address, NEW.country_code,
1546 name_vector, nameaddress_vector, place_centroid);
1553 --RAISE WARNING ' INDEXING: %',NEW;
1555 -- Process area matches (tend to be better quality)
1556 FOR location IN SELECT
1563 ST_Distance(place_centroid, centroid) as distance
1565 WHERE ST_Contains(area, place_centroid) and location_area.rank_search < search_maxrank
1566 ORDER BY ST_Distance(place_centroid, centroid) ASC
1569 --RAISE WARNING ' AREA: % % %',location.keywords,NEW.country_code,location.country_code;
1571 IF NEW.country_code IS NULL THEN
1572 NEW.country_code := location.country_code;
1573 ELSEIF NEW.country_code != location.country_code and location.rank_search > 3 THEN
1574 search_country_code_conflict := true;
1577 -- Add it to the list of search terms
1578 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1579 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1580 address_havelevel[location.rank_address] := true;
1584 -- try using the isin value to find parent places
1585 address_maxrank := search_maxrank;
1586 IF NEW.isin IS NOT NULL THEN
1587 -- Doing isin without a country code seems to be dangerous
1588 IF NEW.country_code is null THEN
1589 NEW.country_code := get_country_code(place_centroid);
1591 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1592 FOR i IN 1..array_upper(isin, 1) LOOP
1593 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1594 IF address_street_word_id IS NOT NULL THEN
1595 --RAISE WARNING ' search: %',address_street_word_id;
1596 FOR location IN SELECT place_id,keywords,rank_search,location_point.country_code,rank_address,
1597 ST_Distance(place_centroid, search_name.centroid) as distance
1598 FROM search_name join location_point using (place_id)
1599 WHERE search_name.name_vector @> ARRAY[address_street_word_id]
1600 AND rank_search < NEW.rank_search
1601 AND (NEW.country_code IS NULL OR search_name.country_code = NEW.country_code OR search_name.address_rank < 4)
1602 ORDER BY ST_distance(NEW.geometry, search_name.centroid) ASC limit 1
1605 IF NEW.country_code IS NULL THEN
1606 NEW.country_code := location.country_code;
1607 ELSEIF NEW.country_code != location.country_code and location.rank_search > 3 THEN
1608 search_country_code_conflict := true;
1611 --RAISE WARNING ' found: %',location.place_id;
1612 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1613 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1615 IF address_maxrank > location.rank_address THEN
1616 address_maxrank := location.rank_address;
1621 FOR i IN address_maxrank..28 LOOP
1622 address_havelevel[i] := true;
1626 -- If we have got a consistent country code from the areas and/or isin then we don't care about points (too inacurate)
1627 bPointCountryCode := NEW.country_code IS NULL;
1630 -- full search using absolute position
1632 search_diameter := 0;
1633 -- 16 = city, anything larger tends to be an area so don't continue
1634 WHILE FALSE AND search_diameter < 1 AND search_maxrank > 16 LOOP
1636 -- RAISE WARNING 'Nearest: % %', search_diameter, search_maxrank;
1638 search_prevdiameter := search_diameter;
1639 IF search_diameter = 0 THEN
1640 search_diameter := 0.001;
1642 search_diameter := search_diameter * 2;
1645 --RAISE WARNING '%', 'SELECT place_id, name, keywords, country_code, rank_address, rank_search,'||
1646 -- 'ST_Distance('||place_geometry_text||', centroid) as distance,'||
1647 -- 'ST_Distance('||place_geometry_text||', centroid) as maxdistance'|| -- this version of postgis doesnt have maxdistance !
1648 -- ' FROM location_point_'||(case when search_maxrank > 26 THEN 26 ELSE search_maxrank end)||
1649 -- ' WHERE ST_DWithin('||place_geometry_text||', centroid, '||search_diameter||') '||
1650 -- ' AND ST_Distance('||place_geometry_text||', centroid) > '||search_prevdiameter||
1651 -- ' ORDER BY ST_Distance('||place_geometry_text||', centroid) ASC';
1654 FOR location IN EXECUTE 'SELECT place_id, name, keywords, country_code, rank_address, rank_search,'||
1655 'ST_Distance('||place_geometry_text||', centroid) as distance,'||
1656 'ST_Distance('||place_geometry_text||', centroid) as maxdistance'|| -- this version of postgis doesnt have maxdistance !
1657 ' FROM location_point_'||(case when search_maxrank > 26 THEN 26 ELSE search_maxrank end)||
1658 ' WHERE ST_DWithin('||place_geometry_text||', centroid, '||search_diameter||') '||
1659 ' AND ST_Distance('||place_geometry_text||', centroid) >= '||search_prevdiameter||
1660 ' ORDER BY ST_Distance('||place_geometry_text||', centroid) ASC'
1663 IF bPointCountryCode THEN
1664 IF NEW.country_code IS NULL THEN
1665 NEW.country_code := location.country_code;
1666 ELSEIF NEW.country_code != location.country_code THEN
1667 search_country_code_conflict := true;
1671 -- Find search words
1672 --RAISE WARNING 'IF % % % %', location.name, location.distance, location.rank_search, search_maxdistance;
1673 --RAISE WARNING ' POINT: % % % % %', location.name, location.rank_search, location.place_id, location.distance, search_maxdistance[location.rank_search];
1674 IF (location.distance < search_maxdistance[location.rank_search]) THEN
1675 --RAISE WARNING ' adding';
1676 -- Add it to the list of search terms, de-duplicate
1677 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1679 iMax := (location.maxdistance*1.5)::float;
1680 FOR i IN location.rank_search..28 LOOP
1681 IF iMax < search_maxdistance[i] THEN
1682 --RAISE WARNING ' setting % to %',i,iMax;
1683 IF iMax > search_mindistance[i] THEN
1684 search_maxdistance[i] := iMax;
1686 search_maxdistance[i] := search_mindistance[i];
1691 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1692 address_havelevel[location.rank_address] := true;
1695 --RAISE WARNING ' Stopped: % % % %', location.rank_search, location.distance, search_maxdistance[location.rank_search], location.name;
1696 IF search_maxrank > location.rank_search THEN
1697 search_maxrank := location.rank_search;
1703 --RAISE WARNING ' POINT LOCATIONS, % %', search_maxrank, search_diameter;
1708 -- Cascading search using nearest parent
1711 IF search_country_code_conflict OR NEW.country_code IS NULL THEN
1712 NEW.country_code := get_country_code(place_centroid);
1715 INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, NEW.country_code,
1716 name_vector, nameaddress_vector, place_centroid);
1718 IF NEW.country_code IS NOT NULL THEN
1719 DELETE FROM place_addressline WHERE place_id = NEW.place_id and address_place_id in (
1720 select address_place_id from place_addressline join placex on (address_place_id = placex.place_id)
1721 where place_addressline.place_id = NEW.place_id and placex.country_code != NEW.country_code and cached_rank_address >= 4);
1731 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1736 --IF OLD.rank_search < 26 THEN
1737 --RAISE WARNING 'delete % % % % %',OLD.place_id,OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1740 -- mark everything linked to this place for re-indexing
1741 UPDATE placex set indexed = false from place_addressline where address_place_id = OLD.place_id and placex.place_id = place_addressline.place_id and indexed;
1743 -- do the actual delete
1744 DELETE FROM location_area where place_id = OLD.place_id;
1745 DELETE FROM location_point where place_id = OLD.place_id;
1746 DELETE FROM location_point_0 where place_id = OLD.place_id;
1747 DELETE FROM location_point_1 where place_id = OLD.place_id;
1748 DELETE FROM location_point_2 where place_id = OLD.place_id;
1749 DELETE FROM location_point_3 where place_id = OLD.place_id;
1750 DELETE FROM location_point_4 where place_id = OLD.place_id;
1751 DELETE FROM location_point_5 where place_id = OLD.place_id;
1752 DELETE FROM location_point_6 where place_id = OLD.place_id;
1753 DELETE FROM location_point_7 where place_id = OLD.place_id;
1754 DELETE FROM location_point_8 where place_id = OLD.place_id;
1755 DELETE FROM location_point_9 where place_id = OLD.place_id;
1756 DELETE FROM location_point_10 where place_id = OLD.place_id;
1757 DELETE FROM location_point_11 where place_id = OLD.place_id;
1758 DELETE FROM location_point_12 where place_id = OLD.place_id;
1759 DELETE FROM location_point_13 where place_id = OLD.place_id;
1760 DELETE FROM location_point_14 where place_id = OLD.place_id;
1761 DELETE FROM location_point_15 where place_id = OLD.place_id;
1762 DELETE FROM location_point_16 where place_id = OLD.place_id;
1763 DELETE FROM location_point_17 where place_id = OLD.place_id;
1764 DELETE FROM location_point_18 where place_id = OLD.place_id;
1765 DELETE FROM location_point_19 where place_id = OLD.place_id;
1766 DELETE FROM location_point_20 where place_id = OLD.place_id;
1767 DELETE FROM location_point_21 where place_id = OLD.place_id;
1768 DELETE FROM location_point_22 where place_id = OLD.place_id;
1769 DELETE FROM location_point_23 where place_id = OLD.place_id;
1770 DELETE FROM location_point_24 where place_id = OLD.place_id;
1771 DELETE FROM location_point_25 where place_id = OLD.place_id;
1772 DELETE FROM location_point_26 where place_id = OLD.place_id;
1773 DELETE FROM search_name where place_id = OLD.place_id;
1774 DELETE FROM place_addressline where place_id = OLD.place_id;
1775 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1783 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1789 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1790 delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1797 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1802 existingplacex RECORD;
1803 existinggeometry GEOMETRY;
1804 existingplace_id bigint;
1808 IF FALSE AND NEW.osm_type = 'R' THEN
1809 RAISE WARNING '-----------------------------------------------------------------------------------';
1810 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1811 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;
1812 RAISE WARNING '%', existingplacex;
1815 -- Just block these - lots and pointless
1816 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1819 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1823 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
1824 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1828 -- Patch in additional country names
1829 -- adminitrative (with typo) is unfortunately hard codes - this probably won't get fixed until v2
1830 IF NEW.admin_level = 2 AND NEW.type = 'adminitrative' AND NEW.country_code is not null THEN
1831 select add_keywords(NEW.name, country_name.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1834 -- Have we already done this place?
1835 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;
1837 -- Get the existing place_id
1838 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;
1840 -- Handle a place changing type by removing the old data
1841 -- My generated 'place' types are causing havok because they overlap with real tags
1842 -- TODO: move them to their own special purpose tag to avoid collisions
1843 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1844 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');
1847 -- RAISE WARNING 'Existing: %',existing.place_id;
1849 -- 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
1850 IF existing.osm_type IS NULL
1851 OR existingplacex.osm_type IS NULL
1852 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1853 -- OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1854 OR (existing.geometry != NEW.geometry AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1855 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1858 -- IF existing.osm_type IS NULL THEN
1859 -- RAISE WARNING 'no existing place';
1861 -- IF existingplacex.osm_type IS NULL THEN
1862 -- RAISE WARNING 'no existing placex %', existingplacex;
1866 -- RAISE WARNING 'delete and replace';
1868 IF existing.osm_type IS NOT NULL THEN
1869 -- 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;
1870 IF existing.rank_search < 26 THEN
1871 -- RAISE WARNING 'replace placex % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1873 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1876 -- RAISE WARNING 'delete and replace2';
1878 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1879 insert into placex values (NEW.place_id
1891 ,NEW.street_place_id
1898 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1903 -- Various ways to do the update
1905 -- Debug, what's changed?
1906 IF FALSE AND existing.rank_search < 26 THEN
1907 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1908 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1910 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1911 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1913 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1914 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1916 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1917 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1919 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1920 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1922 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1923 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1927 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1928 IF existing.geometry != NEW.geometry
1929 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1930 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1933 -- IF existing.rank_search < 26 THEN
1934 -- RAISE WARNING 'existing polygon change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1937 -- Get the version of the geometry actually used (in placex table)
1938 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;
1940 -- Performance limit
1941 IF st_area(NEW.geometry) < 1 AND st_area(existinggeometry) < 1 THEN
1943 -- 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
1944 update placex set indexed = false where indexed and
1945 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1946 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1947 AND rank_search > NEW.rank_search;
1949 update placex set indexed = false where indexed and
1950 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1951 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1952 AND rank_search > NEW.rank_search;
1958 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1959 IF existingplacex.rank_search < 26
1960 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1961 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1962 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1963 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1964 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1965 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1968 -- IF existing.rank_search < 26 THEN
1969 -- RAISE WARNING 'name change only % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1972 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1974 IF st_area(NEW.geometry) < 0.5 THEN
1975 UPDATE placex set indexed = false from place_addressline where address_place_id = existingplacex.place_id
1976 and placex.place_id = place_addressline.place_id and indexed;
1983 -- Anything else has changed - reindex the lot
1984 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1985 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1986 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1987 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1988 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1989 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1991 -- IF existing.rank_search < 26 THEN
1992 -- RAISE WARNING 'other change % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1995 -- performance, can't take the load of re-indexing a whole country / huge area
1996 IF st_area(NEW.geometry) < 0.5 THEN
1997 UPDATE placex set indexed = false from place_addressline where address_place_id = existingplacex.place_id
1998 and placex.place_id = place_addressline.place_id and indexed;
2005 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2006 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2007 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2008 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2009 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2010 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2011 OR existing.geometry != NEW.geometry
2016 housenumber = NEW.housenumber,
2017 street = NEW.street,
2019 postcode = NEW.postcode,
2020 country_code = NEW.country_code,
2021 street_place_id = null,
2022 geometry = NEW.geometry
2023 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2027 housenumber = NEW.housenumber,
2028 street = NEW.street,
2030 postcode = NEW.postcode,
2031 country_code = NEW.country_code,
2032 street_place_id = null,
2034 geometry = NEW.geometry
2035 where place_id = existingplacex.place_id;
2037 result := update_location(existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
2041 -- Abort the add (we modified the existing place instead)
2045 $$ LANGUAGE plpgsql;
2047 CREATE OR REPLACE FUNCTION get_name_by_language(name keyvalue[], languagepref TEXT[]) RETURNS TEXT
2054 IF (array_upper(name, 1) is null) THEN
2058 search := languagepref;
2060 FOR j IN 1..array_upper(search, 1) LOOP
2061 FOR k IN 1..array_upper(name, 1) LOOP
2062 IF (name[k].key = search[j] AND trim(name[k].value) != '') THEN
2063 return trim(name[k].value);
2071 LANGUAGE plpgsql IMMUTABLE;
2073 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2076 searchnodes INTEGER[];
2081 searchnodes := '{}';
2082 FOR j IN 1..array_upper(way_ids, 1) LOOP
2084 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2086 searchnodes := searchnodes | location.nodes;
2090 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2093 LANGUAGE plpgsql IMMUTABLE;
2095 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2106 search := ARRAY['ref'];
2109 UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2111 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2114 select rank_address,name,distance,length(name::text) as namelength
2115 from place_addressline join placex on (address_place_id = placex.place_id)
2116 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2117 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2119 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2120 FOR j IN 1..array_upper(search, 1) LOOP
2121 FOR k IN 1..array_upper(location.name, 1) LOOP
2122 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
2123 result[(100 - location.rank_address)] := trim(location.name[k].value);
2124 found := location.rank_address;
2131 RETURN array_to_string(result,', ');
2136 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2143 searchcountrycode varchar(2);
2144 searchhousenumber TEXT;
2145 searchrankaddress INTEGER;
2149 search := languagepref;
2152 -- UPDATE placex set indexed = false where indexed = true and place_id = for_place_id;
2153 UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2155 select country_code,housenumber,rank_address from placex where place_id = for_place_id into searchcountrycode,searchhousenumber,searchrankaddress;
2158 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
2159 CASE WHEN type = 'postcode' THEN ARRAY[ROW('name',postcode)::keyvalue] ELSE name END as name,
2160 distance,length(name::text) as namelength
2161 from place_addressline join placex on (address_place_id = placex.place_id)
2162 where place_addressline.place_id = for_place_id and ((rank_address > 0 AND rank_address < searchrankaddress) OR address_place_id = for_place_id)
2163 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2164 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
2166 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2167 FOR j IN 1..array_upper(search, 1) LOOP
2168 FOR k IN 1..array_upper(location.name, 1) LOOP
2169 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
2170 result[(100 - location.rank_address)] := trim(location.name[k].value);
2171 found := location.rank_address;
2178 IF searchhousenumber IS NOT NULL AND COALESCE(result[(100 - 28)],'') != searchhousenumber THEN
2179 IF result[(100 - 28)] IS NOT NULL THEN
2180 result[(100 - 29)] := result[(100 - 28)];
2182 result[(100 - 28)] := searchhousenumber;
2185 -- No country polygon - add it from the country_code
2187 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
2188 where place_id = for_place_id limit 1 INTO location;
2189 IF location IS NOT NULL THEN
2190 result[(100 - 4)] := trim(location.name);
2194 RETURN array_to_string(result,', ');
2199 CREATE OR REPLACE FUNCTION get_addressdata_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT[]
2206 searchcountrycode varchar(2);
2207 searchhousenumber TEXT;
2211 search := languagepref;
2214 -- UPDATE placex set indexed = false where indexed = true and place_id = for_place_id;
2215 UPDATE placex set indexed = true where indexed = false and place_id = for_place_id;
2217 select country_code,housenumber from placex where place_id = for_place_id into searchcountrycode,searchhousenumber;
2220 select CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 ELSE rank_address END as rank_address,
2221 name,distance,length(name::text) as namelength
2222 from place_addressline join placex on (address_place_id = placex.place_id)
2223 where place_addressline.place_id = for_place_id and (rank_address > 0 OR address_place_id = for_place_id)
2224 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2225 order by rank_address desc,fromarea desc,distance asc,rank_search desc,namelength desc
2227 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2228 FOR j IN 1..array_upper(search, 1) LOOP
2229 FOR k IN 1..array_upper(location.name, 1) LOOP
2230 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
2231 result[(100 - location.rank_address)] := trim(location.name[k].value);
2232 found := location.rank_address;
2239 IF searchhousenumber IS NOT NULL AND result[(100 - 28)] IS NULL THEN
2240 result[(100 - 28)] := searchhousenumber;
2243 -- No country polygon - add it from the country_code
2245 select get_name_by_language(country_name.name,languagepref) as name from placex join country_name using (country_code)
2246 where place_id = for_place_id limit 1 INTO location;
2247 IF location IS NOT NULL THEN
2248 result[(100 - 4)] := trim(location.name);
2257 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id INTEGER) RETURNS place_boundingbox
2260 result place_boundingbox;
2261 numfeatures integer;
2263 select * from place_boundingbox into result where place_id = search_place_id;
2264 IF result.place_id IS NULL THEN
2265 -- remove isaddress = true because if there is a matching polygon it always wins
2266 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2267 insert into place_boundingbox select place_id,
2268 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
2269 ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
2270 numfeatures, ST_Area(area),
2271 area from location_area where place_id = search_place_id;
2272 select * from place_boundingbox into result where place_id = search_place_id;
2274 IF result.place_id IS NULL THEN
2276 insert into place_boundingbox select address_place_id,
2277 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2278 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2279 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2280 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2281 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)
2282 where address_place_id = search_place_id
2283 -- and (isaddress = true OR place_id = search_place_id)
2284 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2285 group by address_place_id limit 1;
2286 select * from place_boundingbox into result where place_id = search_place_id;
2293 -- don't do the operation if it would be slow
2294 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id INTEGER) RETURNS place_boundingbox
2297 result place_boundingbox;
2298 numfeatures integer;
2301 select * from place_boundingbox into result where place_id = search_place_id;
2302 IF result IS NULL AND rank > 14 THEN
2303 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2304 insert into place_boundingbox select place_id,
2305 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(area)),2)),
2306 ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(area)),3)),
2307 numfeatures, ST_Area(area),
2308 area from location_area where place_id = search_place_id;
2309 select * from place_boundingbox into result where place_id = search_place_id;
2311 IF result IS NULL THEN
2312 select rank_search from placex where place_id = search_place_id into rank;
2315 insert into place_boundingbox select address_place_id,
2316 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2317 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2318 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2319 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2320 from place_addressline join placex using (place_id)
2321 where address_place_id = search_place_id
2322 and (isaddress = true OR place_id = search_place_id)
2323 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2324 group by address_place_id limit 1;
2325 select * from place_boundingbox into result where place_id = search_place_id;
2333 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2336 result place_boundingbox;
2337 numfeatures integer;
2341 housenumber = place.housenumber,
2342 street = place.street,
2344 postcode = place.postcode,
2345 country_code = place.country_code,
2346 street_place_id = null,
2349 where placex.place_id = search_place_id
2350 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2351 and place.class = placex.class and place.type = placex.type;
2352 update placex set indexed = true where place_id = search_place_id and indexed = false;
2358 CREATE OR REPLACE FUNCTION update_place(search_place_id INTEGER) RETURNS BOOLEAN
2361 result place_boundingbox;
2362 numfeatures integer;
2366 housenumber = place.housenumber,
2367 street = place.street,
2369 postcode = place.postcode,
2370 country_code = place.country_code,
2371 street_place_id = null,
2374 where placex.place_id = search_place_id
2375 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2376 and place.class = placex.class and place.type = placex.type;
2377 update placex set indexed = true where place_id = search_place_id and indexed = false;
2383 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2389 ELSEIF rank < 4 THEN
2391 ELSEIF rank < 8 THEN
2393 ELSEIF rank < 12 THEN
2395 ELSEIF rank < 16 THEN
2397 ELSEIF rank = 16 THEN
2399 ELSEIF rank = 17 THEN
2400 RETURN 'Town / Island';
2401 ELSEIF rank = 18 THEN
2402 RETURN 'Village / Hamlet';
2403 ELSEIF rank = 20 THEN
2405 ELSEIF rank = 21 THEN
2406 RETURN 'Postcode Area';
2407 ELSEIF rank = 22 THEN
2408 RETURN 'Croft / Farm / Locality / Islet';
2409 ELSEIF rank = 23 THEN
2410 RETURN 'Postcode Area';
2411 ELSEIF rank = 25 THEN
2412 RETURN 'Postcode Point';
2413 ELSEIF rank = 26 THEN
2414 RETURN 'Street / Major Landmark';
2415 ELSEIF rank = 27 THEN
2416 RETURN 'Minory Street / Path';
2417 ELSEIF rank = 28 THEN
2418 RETURN 'House / Building';
2420 RETURN 'Other: '||rank;
2427 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2433 ELSEIF rank < 2 THEN
2435 ELSEIF rank < 4 THEN
2437 ELSEIF rank = 5 THEN
2439 ELSEIF rank < 8 THEN
2441 ELSEIF rank < 12 THEN
2443 ELSEIF rank < 16 THEN
2445 ELSEIF rank = 16 THEN
2447 ELSEIF rank = 17 THEN
2448 RETURN 'Town / Village / Hamlet';
2449 ELSEIF rank = 20 THEN
2451 ELSEIF rank = 21 THEN
2452 RETURN 'Postcode Area';
2453 ELSEIF rank = 22 THEN
2454 RETURN 'Croft / Farm / Locality / Islet';
2455 ELSEIF rank = 23 THEN
2456 RETURN 'Postcode Area';
2457 ELSEIF rank = 25 THEN
2458 RETURN 'Postcode Point';
2459 ELSEIF rank = 26 THEN
2460 RETURN 'Street / Major Landmark';
2461 ELSEIF rank = 27 THEN
2462 RETURN 'Minory Street / Path';
2463 ELSEIF rank = 28 THEN
2464 RETURN 'House / Building';
2466 RETURN 'Other: '||rank;
2473 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2480 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2481 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2488 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2496 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2498 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2499 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2501 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2509 CREATE AGGREGATE array_agg(INT[])