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;
55 NEWgeometry := ST_PointOnSurface(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(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
68 AS '{modulepath}/nominatim.so', 'transliteration'
69 LANGUAGE c IMMUTABLE STRICT;
71 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
72 AS '{modulepath}/nominatim.so', 'gettokenstring'
73 LANGUAGE c IMMUTABLE STRICT;
75 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
80 o := gettokenstring(transliteration(name));
81 RETURN trim(substr(o,1,length(o)));
84 LANGUAGE 'plpgsql' IMMUTABLE;
86 -- returns NULL if the word is too common
87 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
92 return_word_id INTEGER;
95 lookup_token := trim(lookup_word);
96 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 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);
101 IF count > get_maxwordfreq() THEN
102 return_word_id := NULL;
105 RETURN return_word_id;
110 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
115 return_word_id INTEGER;
117 lookup_token := ' '||trim(lookup_word);
118 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
119 IF return_word_id IS NULL THEN
120 return_word_id := nextval('seq_word');
121 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
123 RETURN return_word_id;
128 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
133 return_word_id INTEGER;
135 lookup_token := ' '||trim(lookup_word);
136 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
137 IF return_word_id IS NULL THEN
138 return_word_id := nextval('seq_word');
139 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
141 RETURN return_word_id;
146 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
151 return_word_id INTEGER;
153 lookup_token := ' '||trim(lookup_word);
154 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
155 IF return_word_id IS NULL THEN
156 return_word_id := nextval('seq_word');
157 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, null);
159 RETURN return_word_id;
164 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
169 return_word_id INTEGER;
171 lookup_token := lookup_class||'='||lookup_type;
172 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
173 IF return_word_id IS NULL THEN
174 return_word_id := nextval('seq_word');
175 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
177 RETURN return_word_id;
182 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
187 return_word_id INTEGER;
189 lookup_token := lookup_class||'='||lookup_type;
190 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
191 RETURN return_word_id;
196 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
201 return_word_id INTEGER;
203 lookup_token := ' '||trim(lookup_word);
204 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;
205 IF return_word_id IS NULL THEN
206 return_word_id := nextval('seq_word');
207 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
209 RETURN return_word_id;
214 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
219 nospace_lookup_token TEXT;
220 return_word_id INTEGER;
222 lookup_token := ' '||trim(lookup_word);
223 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
224 IF return_word_id IS NULL THEN
225 return_word_id := nextval('seq_word');
226 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);
227 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
228 -- IF ' '||nospace_lookup_token != lookup_token THEN
229 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
232 RETURN return_word_id;
237 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
242 RETURN getorcreate_name_id(lookup_word, '');
247 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
252 return_word_id INTEGER;
254 lookup_token := trim(lookup_word);
255 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
256 RETURN return_word_id;
259 LANGUAGE plpgsql IMMUTABLE;
261 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
266 return_word_id INTEGER;
268 lookup_token := ' '||trim(lookup_word);
269 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
270 RETURN return_word_id;
273 LANGUAGE plpgsql IMMUTABLE;
275 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
282 IF array_upper(a, 1) IS NULL THEN
285 IF array_upper(b, 1) IS NULL THEN
289 FOR i IN 1..array_upper(b, 1) LOOP
290 IF NOT (ARRAY[b[i]] <@ r) THEN
297 LANGUAGE plpgsql IMMUTABLE;
299 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
308 FOR item IN SELECT (each(src)).* LOOP
310 s := make_standard_name(item.value);
311 w := getorcreate_country(s, lookup_country_code);
313 words := regexp_split_to_array(item.value, E'[,;()]');
314 IF array_upper(words, 1) != 1 THEN
315 FOR j IN 1..array_upper(words, 1) LOOP
316 s := make_standard_name(words[j]);
318 w := getorcreate_country(s, lookup_country_code);
327 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
337 result := '{}'::INTEGER[];
339 FOR item IN SELECT (each(src)).* LOOP
341 s := make_standard_name(item.value);
343 w := getorcreate_name_id(s, item.value);
345 IF not(ARRAY[w] <@ result) THEN
346 result := result || w;
349 words := string_to_array(s, ' ');
350 IF array_upper(words, 1) IS NOT NULL THEN
351 FOR j IN 1..array_upper(words, 1) LOOP
352 IF (words[j] != '') THEN
353 w = getorcreate_word_id(words[j]);
354 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
355 result := result || w;
361 words := regexp_split_to_array(item.value, E'[,;()]');
362 IF array_upper(words, 1) != 1 THEN
363 FOR j IN 1..array_upper(words, 1) LOOP
364 s := make_standard_name(words[j]);
366 w := getorcreate_word_id(s);
367 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
368 result := result || w;
374 s := regexp_replace(item.value, '市$', '');
375 IF s != item.value THEN
376 s := make_standard_name(s);
378 w := getorcreate_name_id(s, item.value);
379 IF NOT (ARRAY[w] <@ result) THEN
380 result := result || w;
390 LANGUAGE plpgsql IMMUTABLE;
392 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
402 result := '{}'::INTEGER[];
404 s := make_standard_name(src);
405 w := getorcreate_name_id(s, src);
407 IF NOT (ARRAY[w] <@ result) THEN
408 result := result || w;
411 words := string_to_array(s, ' ');
412 IF array_upper(words, 1) IS NOT NULL THEN
413 FOR j IN 1..array_upper(words, 1) LOOP
414 IF (words[j] != '') THEN
415 w = getorcreate_word_id(words[j]);
416 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
417 result := result || w;
423 words := regexp_split_to_array(src, E'[,;()]');
424 IF array_upper(words, 1) != 1 THEN
425 FOR j IN 1..array_upper(words, 1) LOOP
426 s := make_standard_name(words[j]);
428 w := getorcreate_word_id(s);
429 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
430 result := result || w;
436 s := regexp_replace(src, '市$', '');
438 s := make_standard_name(s);
440 w := getorcreate_name_id(s, src);
441 IF NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
450 LANGUAGE plpgsql IMMUTABLE;
452 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
459 IF (wordscores is null OR words is null) THEN
464 FOR idxword in 1 .. array_upper(words, 1) LOOP
465 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
466 IF wordscores[idxscores].word = words[idxword] THEN
467 result := result + wordscores[idxscores].score;
475 LANGUAGE plpgsql IMMUTABLE;
477 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
480 place_centre GEOMETRY;
483 place_centre := ST_PointOnSurface(place);
485 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
487 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
489 -- Try for OSM fallback data
490 -- The order is to deal with places like HongKong that are 'states' within another polygon
491 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
493 RETURN nearcountry.country_code;
496 -- Try for a OSM polygon
497 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
499 RETURN nearcountry.country_code;
502 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
504 -- Natural earth data
505 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
507 RETURN nearcountry.country_code;
510 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
513 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
520 -- Natural earth data
521 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
523 RETURN nearcountry.country_code;
526 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
527 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
529 -- RETURN nearcountry.country_code;
532 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
534 -- Still not in a country - try nearest within ~12 miles of a country
535 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
536 -- order by st_distance(geometry, place) limit 1
538 -- RETURN nearcountry.country_code;
544 LANGUAGE plpgsql IMMUTABLE;
546 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
551 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
553 RETURN nearcountry.country_code;
555 RETURN get_country_code(place);
558 LANGUAGE plpgsql IMMUTABLE;
560 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
565 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
567 RETURN lower(nearcountry.country_default_language_code);
572 LANGUAGE plpgsql IMMUTABLE;
574 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
577 place_centre GEOMETRY;
580 FOR nearcountry IN select partition from country_name where country_code = in_country_code
582 RETURN nearcountry.partition;
587 LANGUAGE plpgsql IMMUTABLE;
589 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
593 DELETE FROM location_area where place_id = OLD_place_id;
594 -- TODO:location_area
600 CREATE OR REPLACE FUNCTION add_location(
602 country_code varchar(2),
606 rank_address INTEGER,
621 IF rank_search > 25 THEN
622 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
625 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
627 x := deleteLocationArea(partition, place_id);
630 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
633 centroid := ST_Centroid(geometry);
635 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
636 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
639 ELSEIF rank_search < 26 THEN
642 IF rank_address = 0 THEN
644 ELSEIF rank_search <= 14 THEN
646 ELSEIF rank_search <= 15 THEN
648 ELSEIF rank_search <= 16 THEN
650 ELSEIF rank_search <= 17 THEN
652 ELSEIF rank_search <= 21 THEN
654 ELSEIF rank_search = 25 THEN
658 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
660 secgeo := ST_Buffer(geometry, diameter);
661 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
666 secgeo := ST_Buffer(geometry, 0.0002);
667 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
670 secgeo := ST_Buffer(geometry, 0.001);
671 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
680 CREATE OR REPLACE FUNCTION update_location(
683 place_country_code varchar(2),
686 rank_address INTEGER,
694 b := deleteLocationArea(partition, place_id);
695 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
696 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
701 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
712 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
713 FOR childplace IN select * from search_name,place_addressline
714 where address_place_id = parent_place_id
715 and search_name.place_id = place_addressline.place_id
717 delete from search_name where place_id = childplace.place_id;
718 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
719 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
721 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
722 childplace.name_vector := childplace.name_vector || to_add;
724 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
725 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
726 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
734 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
737 newkeywords INTEGER[];
738 addedkeywords INTEGER[];
739 removedkeywords INTEGER[];
743 newkeywords := make_keywords(name);
744 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
745 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
746 where place_id = OLD_place_id into addedkeywords, removedkeywords;
748 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
750 IF #removedkeywords > 0 THEN
751 -- abort due to tokens removed
755 IF #addedkeywords > 0 THEN
756 -- short circuit - no changes
760 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
761 RETURN search_name_add_words(OLD_place_id, addedkeywords);
767 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
779 orginalstartnumber INTEGER;
780 originalnumberrange INTEGER;
783 search_place_id BIGINT;
786 havefirstpoint BOOLEAN;
790 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
792 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
793 select nodes from planet_osm_ways where id = wayid INTO waynodes;
794 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
795 IF array_upper(waynodes, 1) IS NOT NULL THEN
797 havefirstpoint := false;
799 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
801 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
802 IF search_place_id IS NULL THEN
803 -- null record of right type
804 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
805 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
806 IF nextnode.geometry IS NULL THEN
807 -- we don't have any information about this point, most likely
808 -- because an excerpt was updated and the node never imported
809 -- because the interpolation is outside the region of the excerpt.
814 select * from placex where place_id = search_place_id INTO nextnode;
817 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
819 IF havefirstpoint THEN
821 -- add point to the line string
822 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
823 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
825 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
827 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
829 IF startnumber != endnumber THEN
831 linestr := linestr || ')';
832 --RAISE WARNING 'linestr %',linestr;
833 linegeo := ST_GeomFromText(linestr,4326);
834 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
835 IF (startnumber > endnumber) THEN
836 housenum := endnumber;
837 endnumber := startnumber;
838 startnumber := housenum;
839 linegeo := ST_Reverse(linegeo);
841 orginalstartnumber := startnumber;
842 originalnumberrange := endnumber - startnumber;
844 -- Too much broken data worldwide for this test to be worth using
845 -- IF originalnumberrange > 500 THEN
846 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
849 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
850 startnumber := startnumber + 1;
853 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
854 startnumber := startnumber + 2;
856 ELSE -- everything else assumed to be 'all'
857 startnumber := startnumber + 1;
861 endnumber := endnumber - 1;
862 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
863 FOR housenum IN startnumber..endnumber BY stepsize LOOP
864 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
865 -- ideally postcodes should move up to the way
866 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
867 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
868 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
869 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));
870 newpoints := newpoints + 1;
871 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
874 havefirstpoint := false;
878 IF NOT havefirstpoint THEN
879 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
880 IF startnumber IS NOT NULL AND startnumber > 0 THEN
881 havefirstpoint := true;
882 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
883 prevnode := nextnode;
885 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
891 --RAISE WARNING 'interpolation points % ',newpoints;
898 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
904 country_code VARCHAR(2);
905 default_language VARCHAR(10);
909 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
912 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
913 -- RAISE WARNING 'bad highway %',NEW.osm_id;
916 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
917 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
921 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
922 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
923 RAISE WARNING 'invalid geometry %',NEW.osm_id;
927 IF NEW.osm_type = 'R' THEN
928 -- invalid multipolygons can crash postgis, don't even bother to try!
931 NEW.geometry := ST_buffer(NEW.geometry,0);
932 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
933 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
938 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
940 NEW.place_id := nextval('seq_place');
941 NEW.indexed_status := 1; --STATUS_NEW
943 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
945 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
946 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
948 -- copy 'name' to or from the default language (if there is a default language)
949 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
950 default_language := get_country_language_code(NEW.calculated_country_code);
951 IF default_language IS NOT NULL THEN
952 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
953 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
954 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
955 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
960 IF NEW.admin_level > 15 THEN
961 NEW.admin_level := 15;
964 IF NEW.housenumber IS NOT NULL THEN
965 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
968 IF NEW.osm_type = 'X' THEN
969 -- E'X'ternal records should already be in the right format so do nothing
971 NEW.rank_search := 30;
972 NEW.rank_address := NEW.rank_search;
974 -- By doing in postgres we have the country available to us - currently only used for postcode
975 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
977 IF NEW.postcode IS NULL THEN
978 -- most likely just a part of a multipolygon postcode boundary, throw it away
982 NEW.name := 'ref'=>NEW.postcode;
984 IF NEW.calculated_country_code = 'gb' THEN
986 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
987 NEW.rank_search := 25;
988 NEW.rank_address := 5;
989 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
990 NEW.rank_search := 23;
991 NEW.rank_address := 5;
992 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
993 NEW.rank_search := 21;
994 NEW.rank_address := 5;
997 ELSEIF NEW.calculated_country_code = 'de' THEN
999 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1000 NEW.rank_search := 21;
1001 NEW.rank_address := 11;
1005 -- Guess at the postcode format and coverage (!)
1006 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1007 NEW.rank_search := 21;
1008 NEW.rank_address := 11;
1010 -- Does it look splitable into and area and local code?
1011 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1013 IF postcode IS NOT NULL THEN
1014 NEW.rank_search := 25;
1015 NEW.rank_address := 11;
1016 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1017 NEW.rank_search := 21;
1018 NEW.rank_address := 11;
1023 ELSEIF NEW.class = 'place' THEN
1024 IF NEW.type in ('continent') THEN
1025 NEW.rank_search := 2;
1026 NEW.rank_address := NEW.rank_search;
1027 NEW.calculated_country_code := NULL;
1028 ELSEIF NEW.type in ('sea') THEN
1029 NEW.rank_search := 2;
1030 NEW.rank_address := 0;
1031 NEW.calculated_country_code := NULL;
1032 ELSEIF NEW.type in ('country') THEN
1033 NEW.rank_search := 4;
1034 NEW.rank_address := NEW.rank_search;
1035 ELSEIF NEW.type in ('state') THEN
1036 NEW.rank_search := 8;
1037 NEW.rank_address := NEW.rank_search;
1038 ELSEIF NEW.type in ('region') THEN
1039 NEW.rank_search := 18; -- dropped from previous value of 10
1040 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1041 ELSEIF NEW.type in ('county') THEN
1042 NEW.rank_search := 12;
1043 NEW.rank_address := NEW.rank_search;
1044 ELSEIF NEW.type in ('city') THEN
1045 NEW.rank_search := 16;
1046 NEW.rank_address := NEW.rank_search;
1047 ELSEIF NEW.type in ('island') THEN
1048 NEW.rank_search := 17;
1049 NEW.rank_address := 0;
1050 ELSEIF NEW.type in ('town') THEN
1051 NEW.rank_search := 18;
1052 NEW.rank_address := 16;
1053 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1054 NEW.rank_search := 19;
1055 NEW.rank_address := 16;
1056 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1057 NEW.rank_search := 18;
1058 NEW.rank_address := 17;
1059 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1060 NEW.rank_search := 17;
1061 NEW.rank_address := 18;
1062 ELSEIF NEW.type in ('moor') THEN
1063 NEW.rank_search := 17;
1064 NEW.rank_address := 0;
1065 ELSEIF NEW.type in ('national_park') THEN
1066 NEW.rank_search := 18;
1067 NEW.rank_address := 18;
1068 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1069 NEW.rank_search := 20;
1070 NEW.rank_address := NEW.rank_search;
1071 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1072 NEW.rank_search := 20;
1073 NEW.rank_address := 0;
1074 -- Irish townlands, tagged as place=locality and locality=townland
1075 IF (NEW.extratags -> 'locality') = 'townland' THEN
1076 NEW.rank_address := 20;
1078 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1079 NEW.rank_search := 22;
1080 NEW.rank_address := 22;
1081 ELSEIF NEW.type in ('airport','street') THEN
1082 NEW.rank_search := 26;
1083 NEW.rank_address := NEW.rank_search;
1084 ELSEIF NEW.type in ('house','building') THEN
1085 NEW.rank_search := 30;
1086 NEW.rank_address := NEW.rank_search;
1087 ELSEIF NEW.type in ('houses') THEN
1088 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1089 -- insert new point into place for each derived building
1090 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1091 NEW.rank_search := 28;
1092 NEW.rank_address := 0;
1095 ELSEIF NEW.class = 'boundary' THEN
1096 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1097 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1100 NEW.rank_search := NEW.admin_level * 2;
1101 NEW.rank_address := NEW.rank_search;
1102 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1103 NEW.rank_search := 22;
1104 NEW.rank_address := NEW.rank_search;
1105 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1106 NEW.rank_search := 18;
1107 NEW.rank_address := 0;
1108 -- any feature more than 5 square miles is probably worth indexing
1109 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1110 NEW.rank_search := 22;
1111 NEW.rank_address := NEW.rank_search;
1112 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1113 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1114 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1116 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1118 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1120 ELSEIF NEW.class = 'waterway' THEN
1121 NEW.rank_address := 17;
1122 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
1123 NEW.rank_search := 27;
1124 NEW.rank_address := NEW.rank_search;
1125 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1126 NEW.rank_search := 26;
1127 NEW.rank_address := NEW.rank_search;
1128 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1129 NEW.rank_search := 4;
1130 NEW.rank_address := NEW.rank_search;
1131 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1137 IF NEW.rank_search > 30 THEN
1138 NEW.rank_search := 30;
1141 IF NEW.rank_address > 30 THEN
1142 NEW.rank_address := 30;
1145 IF (NEW.extratags -> 'capital') = 'yes' THEN
1146 NEW.rank_search := NEW.rank_search - 1;
1149 -- a country code make no sense below rank 4 (country)
1150 IF NEW.rank_address < 4 THEN
1151 NEW.calculated_country_code := NULL;
1154 -- Block import below rank 22
1155 -- IF NEW.rank_search > 22 THEN
1159 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1161 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1163 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1164 -- Performance: We just can't handle re-indexing for country level changes
1165 IF st_area(NEW.geometry) < 1 THEN
1166 -- mark items within the geometry for re-indexing
1167 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1169 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1170 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1171 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null);
1172 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1173 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null);
1176 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1178 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1179 IF NEW.type='postcode' THEN
1181 ELSEIF NEW.rank_search < 16 THEN
1183 ELSEIF NEW.rank_search < 18 THEN
1185 ELSEIF NEW.rank_search < 20 THEN
1187 ELSEIF NEW.rank_search = 21 THEN
1189 ELSEIF NEW.rank_search < 24 THEN
1191 ELSEIF NEW.rank_search < 26 THEN
1192 diameter := 0.002; -- 100 to 200 meters
1193 ELSEIF NEW.rank_search < 28 THEN
1194 diameter := 0.001; -- 50 to 100 meters
1196 IF diameter > 0 THEN
1197 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1198 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null);
1203 -- add to tables for special search
1204 -- Note: won't work on initial import because the classtype tables
1205 -- do not yet exist. It won't hurt either.
1206 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1207 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1209 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1210 USING NEW.place_id, ST_Centroid(NEW.geometry);
1214 -- IF NEW.rank_search < 26 THEN
1215 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1224 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1229 place_centroid GEOMETRY;
1231 search_maxdistance FLOAT[];
1232 search_mindistance FLOAT[];
1233 address_havelevel BOOLEAN[];
1234 -- search_scores wordscore[];
1235 -- search_scores_pos INTEGER;
1242 relation_members TEXT[];
1244 linkedplacex RECORD;
1245 search_diameter FLOAT;
1246 search_prevdiameter FLOAT;
1247 search_maxrank INTEGER;
1248 address_maxrank INTEGER;
1249 address_street_word_id INTEGER;
1250 parent_place_id_rank BIGINT;
1255 location_rank_search INTEGER;
1256 location_distance FLOAT;
1257 location_parent GEOMETRY;
1258 location_isaddress BOOLEAN;
1262 default_language TEXT;
1263 name_vector INTEGER[];
1264 nameaddress_vector INTEGER[];
1266 linked_node_id BIGINT;
1272 IF OLD.indexed_status = 100 THEN
1273 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1274 delete from placex where place_id = OLD.place_id;
1278 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1282 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1284 --RAISE WARNING '%',NEW.place_id;
1285 --RAISE WARNING '%', NEW;
1287 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1288 -- Silently do nothing
1292 IF OLD.indexed_status != 0 THEN
1293 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1295 NEW.indexed_date = now();
1297 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1298 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1302 IF OLD.indexed_status > 0 THEN
1303 result := deleteSearchName(NEW.partition, NEW.place_id);
1304 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1305 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1306 result := deleteRoad(NEW.partition, NEW.place_id);
1307 result := deleteLocationArea(NEW.partition, NEW.place_id);
1308 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1311 -- Speed up searches - just use the centroid of the feature
1312 -- cheaper but less acurate
1313 place_centroid := ST_PointOnSurface(NEW.geometry);
1314 NEW.centroid := null;
1316 -- reclaculate country and partition
1317 IF NEW.rank_search >= 4 THEN
1318 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1319 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1321 NEW.calculated_country_code := NULL;
1323 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1324 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1326 -- Adding ourselves to the list simplifies address calculations later
1327 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1329 -- What level are we searching from
1330 search_maxrank := NEW.rank_search;
1332 -- Thought this wasn't needed but when we add new languages to the country_name table
1333 -- we need to update the existing names
1334 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1335 default_language := get_country_language_code(NEW.calculated_country_code);
1336 IF default_language IS NOT NULL THEN
1337 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1338 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1339 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1340 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1345 -- Initialise the name vector using our name
1346 name_vector := make_keywords(NEW.name);
1347 nameaddress_vector := '{}'::int[];
1349 -- some tag combinations add a special id for search
1350 tagpairid := get_tagpair(NEW.class,NEW.type);
1351 IF tagpairid IS NOT NULL THEN
1352 name_vector := name_vector + tagpairid;
1356 address_havelevel[i] := false;
1359 NEW.importance := null;
1360 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1361 IF NEW.importance IS NULL THEN
1362 select language||':'||title,importance from wikipedia_article where osm_type = NEW.osm_type and osm_id = NEW.osm_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
1365 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1367 -- For low level elements we inherit from our parent road
1368 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1370 --RAISE WARNING 'finding street for %', NEW;
1372 NEW.parent_place_id := null;
1374 -- to do that we have to find our parent road
1375 -- Copy data from linked items (points on ways, addr:street links, relations)
1376 -- Note that addr:street links can only be indexed once the street itself is indexed
1377 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1379 -- Is this node part of a relation?
1380 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1382 -- At the moment we only process one type of relation - associatedStreet
1383 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1384 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1385 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1386 --RAISE WARNING 'node in relation %',relation;
1387 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1388 and rank_search = 26 INTO NEW.parent_place_id;
1394 --RAISE WARNING 'x1';
1395 -- Is this node part of a way?
1396 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1397 --RAISE WARNING '%', way;
1398 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1400 --RAISE WARNING '%', location;
1401 -- Way IS a road then we are on it - that must be our road
1402 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1403 --RAISE WARNING 'node in way that is a street %',location;
1404 NEW.parent_place_id := location.place_id;
1407 -- Is the WAY part of a relation
1408 IF NEW.parent_place_id IS NULL THEN
1409 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] 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.parent_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.parent_place_id;
1424 -- If the way contains an explicit name of a street copy it
1425 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1426 --RAISE WARNING 'node in way that has a streetname %',location;
1427 NEW.street := location.street;
1430 -- If this way is a street interpolation line then it is probably as good as we are going to get
1431 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1432 -- Try and find a way that is close roughly parellel to this line
1433 FOR relation IN SELECT place_id FROM placex
1434 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1435 and st_geometrytype(location.geometry) in ('ST_LineString')
1436 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1437 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1438 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1440 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1441 NEW.parent_place_id := relation.place_id;
1450 --RAISE WARNING 'x2';
1452 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1453 -- Is this way part of a relation?
1454 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1456 -- At the moment we only process one type of relation - associatedStreet
1457 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1458 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1459 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1460 --RAISE WARNING 'way that is in a relation %',relation;
1461 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1462 and rank_search = 26 INTO NEW.parent_place_id;
1469 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1471 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1472 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1473 IF address_street_word_id IS NOT NULL THEN
1474 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1475 NEW.parent_place_id := location.place_id;
1480 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1481 -- Still nothing, just use the nearest road
1482 IF NEW.parent_place_id IS NULL THEN
1483 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1484 NEW.parent_place_id := location.place_id;
1489 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1491 -- If we didn't find any road fallback to standard method
1492 IF NEW.parent_place_id IS NOT NULL THEN
1494 -- Add the street to the address as zero distance to force to front of list
1495 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1496 address_havelevel[26] := true;
1498 -- Import address details from parent, reclculating distance in process
1499 -- 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
1500 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1501 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1503 -- Get the details of the parent road
1504 select * from search_name where place_id = NEW.parent_place_id INTO location;
1505 NEW.calculated_country_code := location.country_code;
1507 --RAISE WARNING '%', NEW.name;
1508 -- If there is no name it isn't searchable, don't bother to create a search record
1509 IF NEW.name is NULL THEN
1513 -- Merge address from parent
1514 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1516 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1517 -- Just be happy with inheriting from parent road only
1519 IF NEW.rank_search <= 25 THEN
1520 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1523 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1530 -- RAISE WARNING ' INDEXING Started:';
1531 -- RAISE WARNING ' INDEXING: %',NEW;
1533 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1535 -- see if we have any special relation members
1536 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1538 -- RAISE WARNING 'get_osm_rel_members, label';
1539 IF relation_members IS NOT NULL THEN
1540 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1542 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1543 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1545 -- If we don't already have one use this as the centre point of the geometry
1546 IF NEW.centroid IS NULL THEN
1547 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1550 -- merge in the label name, re-init word vector
1551 IF NOT linkedPlacex.name IS NULL THEN
1552 NEW.name := linkedPlacex.name || NEW.name;
1553 name_vector := make_keywords(NEW.name);
1556 -- merge in extra tags
1557 IF NOT linkedPlacex.extratags IS NULL THEN
1558 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1561 -- mark the linked place (excludes from search results)
1562 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1568 IF NEW.centroid IS NULL THEN
1570 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1572 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1573 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1575 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1576 -- But that can be fixed by explicitly setting the label in the data
1577 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1578 AND NEW.rank_address = linkedPlacex.rank_address THEN
1581 -- If we don't already have one use this as the centre point of the geometry
1582 IF NEW.centroid IS NULL THEN
1583 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1586 -- merge in the name, re-init word vector
1587 IF NOT linkedPlacex.name IS NULL THEN
1588 NEW.name := linkedPlacex.name || NEW.name;
1589 name_vector := make_keywords(NEW.name);
1592 -- merge in extra tags
1593 IF NOT linkedPlacex.extratags IS NULL THEN
1594 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1597 -- mark the linked place (excludes from search results)
1598 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1600 -- keep a note of the node id in case we need it for wikipedia in a bit
1601 linked_node_id := linkedPlacex.osm_id;
1611 -- not found one yet? how about doing a name search
1612 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1614 FOR linkedPlacex IN select placex.* from placex WHERE
1615 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1616 AND placex.rank_address = NEW.rank_address
1617 AND placex.place_id != NEW.place_id
1618 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1619 AND st_covers(NEW.geometry, placex.geometry)
1622 -- If we don't already have one use this as the centre point of the geometry
1623 IF NEW.centroid IS NULL THEN
1624 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1627 -- merge in the name, re-init word vector
1628 NEW.name := linkedPlacex.name || NEW.name;
1629 name_vector := make_keywords(NEW.name);
1631 -- merge in extra tags
1632 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1634 -- mark the linked place (excludes from search results)
1635 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1637 -- keep a note of the node id in case we need it for wikipedia in a bit
1638 linked_node_id := linkedPlacex.osm_id;
1642 IF NEW.centroid IS NOT NULL THEN
1643 place_centroid := NEW.centroid;
1646 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1647 IF NEW.importance is null THEN
1648 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1650 -- Still null? how about looking it up by the node id
1651 IF NEW.importance IS NULL THEN
1652 select language||':'||title,importance from wikipedia_article where osm_type = 'N'::char(1) and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
1657 -- make sure all names are in the word table
1658 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1659 perform create_country(NEW.name, lower(NEW.country_code));
1662 NEW.parent_place_id = 0;
1663 parent_place_id_rank = 0;
1665 -- convert isin to array of tokenids
1666 isin_tokens := '{}'::int[];
1667 IF NEW.isin IS NOT NULL THEN
1668 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1669 IF array_upper(isin, 1) IS NOT NULL THEN
1670 FOR i IN 1..array_upper(isin, 1) LOOP
1671 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1672 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1673 isin_tokens := isin_tokens || address_street_word_id;
1678 IF NEW.postcode IS NOT NULL THEN
1679 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1680 IF array_upper(isin, 1) IS NOT NULL THEN
1681 FOR i IN 1..array_upper(isin, 1) LOOP
1682 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1683 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1684 isin_tokens := isin_tokens || address_street_word_id;
1689 -- RAISE WARNING 'ISIN: %', isin_tokens;
1691 -- Process area matches
1692 location_rank_search := 0;
1693 location_distance := 0;
1694 location_parent := NULL;
1695 -- added ourself as address already
1696 address_havelevel[NEW.rank_address] := true;
1697 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1698 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1700 --RAISE WARNING ' AREA: %',location;
1702 IF location.rank_address != location_rank_search THEN
1703 location_rank_search := location.rank_address;
1704 location_distance := location.distance * 1.5;
1707 IF location.distance < location_distance OR NOT location.isguess THEN
1709 location_isaddress := NOT address_havelevel[location.rank_address];
1710 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1711 location_isaddress := ST_Contains(location_parent,location.centroid);
1714 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1715 -- Add it to the list of search terms
1716 IF location.rank_search > 4 THEN
1717 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1719 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1721 IF location_isaddress THEN
1722 address_havelevel[location.rank_address] := true;
1723 IF NOT location.isguess THEN
1724 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1728 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1730 IF location.rank_address > parent_place_id_rank THEN
1731 NEW.parent_place_id = location.place_id;
1732 parent_place_id_rank = location.rank_address;
1739 -- try using the isin value to find parent places
1740 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1741 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1742 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1743 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1745 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1747 --RAISE WARNING ' ISIN: %',location;
1749 IF location.rank_search > 4 THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1751 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1752 address_havelevel[location.rank_address] := true;
1754 IF location.rank_address > parent_place_id_rank THEN
1755 NEW.parent_place_id = location.place_id;
1756 parent_place_id_rank = location.rank_address;
1766 -- for long ways we should add search terms for the entire length
1767 IF st_length(NEW.geometry) > 0.05 THEN
1769 location_rank_search := 0;
1770 location_distance := 0;
1772 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1774 IF location.rank_address != location_rank_search THEN
1775 location_rank_search := location.rank_address;
1776 location_distance := location.distance * 1.5;
1779 IF location.rank_search > 4 AND location.distance < location_distance THEN
1781 -- Add it to the list of search terms
1782 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1783 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1791 -- if we have a name add this to the name search table
1792 IF NEW.name IS NOT NULL THEN
1794 IF NEW.rank_search <= 25 THEN
1795 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1798 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1799 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1802 result := insertSearchName(NEW.partition, NEW.place_id, NEW.calculated_country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1804 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.calculated_country_code, name_vector, nameaddress_vector, place_centroid);
1807 -- If we've not managed to pick up a better one - default centroid
1808 IF NEW.centroid IS NULL THEN
1809 NEW.centroid := place_centroid;
1819 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1825 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1827 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1828 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1829 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1830 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1832 IF OLD.rank_address < 30 THEN
1834 -- mark everything linked to this place for re-indexing
1835 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1836 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1837 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1839 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1840 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1842 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1843 b := deleteRoad(OLD.partition, OLD.place_id);
1845 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1846 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1847 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1851 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1853 IF OLD.rank_address < 26 THEN
1854 b := deleteLocationArea(OLD.partition, OLD.place_id);
1857 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1859 IF OLD.name is not null THEN
1860 b := deleteSearchName(OLD.partition, OLD.place_id);
1863 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1865 DELETE FROM place_addressline where place_id = OLD.place_id;
1867 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1869 -- remove from tables for special search
1870 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1871 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1873 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1876 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1884 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1890 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1892 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1893 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1894 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1899 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;
1907 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1912 existingplacex RECORD;
1913 existinggeometry GEOMETRY;
1914 existingplace_id BIGINT;
1919 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1920 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1922 IF FALSE and NEW.osm_type = 'R' THEN
1923 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;
1924 --DEBUG: RAISE WARNING '%', existingplacex;
1927 -- Just block these - lots and pointless
1928 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1931 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1935 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
1936 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1937 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1938 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1942 -- Patch in additional country names
1943 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1944 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1947 -- Have we already done this place?
1948 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;
1950 -- Get the existing place_id
1951 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;
1953 -- Handle a place changing type by removing the old data
1954 -- My generated 'place' types are causing havok because they overlap with real keys
1955 -- TODO: move them to their own special purpose key/class to avoid collisions
1956 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1957 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');
1960 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1961 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1964 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1965 AND st_area(existing.geometry) > 0.02
1966 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1967 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1969 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1970 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1974 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1975 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1977 -- 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
1978 IF existingplacex.osm_type IS NULL THEN
1980 IF existing.osm_type IS NOT NULL THEN
1981 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1984 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1985 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1986 street, isin, postcode, country_code, extratags, geometry)
1987 values (NEW.osm_type
2002 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2007 -- Various ways to do the update
2009 -- Debug, what's changed?
2011 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2012 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2014 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2015 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2017 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2018 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2020 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2021 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2023 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2024 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2026 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2027 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2031 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2032 IF existing.geometry::text != NEW.geometry::text
2033 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2034 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2037 -- Get the version of the geometry actually used (in placex table)
2038 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;
2040 -- Performance limit
2041 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2043 -- 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
2044 update placex set indexed_status = 2 where indexed_status = 0 and
2045 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2046 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2047 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2049 update placex set indexed_status = 2 where indexed_status = 0 and
2050 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2051 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2052 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2058 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2059 IF FALSE AND existingplacex.rank_search < 26
2060 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2061 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2062 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2063 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2064 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2065 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2068 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2070 IF st_area(NEW.geometry) < 0.5 THEN
2071 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2072 and placex.place_id = place_addressline.place_id and indexed_status = 0
2073 and (rank_search < 28 or name is not null);
2080 -- Anything else has changed - reindex the lot
2081 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2082 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2083 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2084 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2085 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2086 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2088 -- performance, can't take the load of re-indexing a whole country / huge area
2089 IF st_area(NEW.geometry) < 0.5 THEN
2090 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2091 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2098 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2099 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2100 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2101 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2102 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2103 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2104 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2105 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2106 OR existing.geometry::text != NEW.geometry::text
2111 housenumber = NEW.housenumber,
2112 street = NEW.street,
2114 postcode = NEW.postcode,
2115 country_code = NEW.country_code,
2116 extratags = NEW.extratags,
2117 geometry = NEW.geometry
2118 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2122 housenumber = NEW.housenumber,
2123 street = NEW.street,
2125 postcode = NEW.postcode,
2126 country_code = NEW.country_code,
2127 parent_place_id = null,
2128 extratags = NEW.extratags,
2130 geometry = NEW.geometry
2131 where place_id = existingplacex.place_id;
2135 -- Abort the add (we modified the existing place instead)
2139 $$ LANGUAGE plpgsql;
2141 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2148 IF name is null THEN
2152 search := languagepref;
2154 FOR j IN 1..array_upper(search, 1) LOOP
2155 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2156 return trim(name->search[j]);
2163 LANGUAGE plpgsql IMMUTABLE;
2165 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2168 searchnodes INTEGER[];
2173 searchnodes := '{}';
2174 FOR j IN 1..array_upper(way_ids, 1) LOOP
2176 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2178 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2179 searchnodes := searchnodes || location.nodes;
2184 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2187 LANGUAGE plpgsql IMMUTABLE;
2189 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2200 search := ARRAY['ref'];
2203 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2206 select rank_address,name,distance,length(name::text) as namelength
2207 from place_addressline join placex on (address_place_id = placex.place_id)
2208 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2209 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2211 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2212 FOR j IN 1..array_upper(search, 1) LOOP
2213 FOR k IN 1..array_upper(location.name, 1) LOOP
2214 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
2215 result[(100 - location.rank_address)] := trim(location.name[k].value);
2216 found := location.rank_address;
2223 RETURN array_to_string(result,', ');
2228 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2240 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2241 currresult := trim(get_name_by_language(location.name, languagepref));
2242 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2243 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2244 prevresult := currresult;
2248 RETURN array_to_string(result,', ');
2253 DROP TYPE addressline CASCADE;
2254 create type addressline as (
2261 admin_level INTEGER,
2264 rank_address INTEGER,
2268 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2271 for_place_id BIGINT;
2276 countrylocation RECORD;
2277 searchcountrycode varchar(2);
2278 searchhousenumber TEXT;
2279 searchhousename HSTORE;
2280 searchrankaddress INTEGER;
2281 searchpostcode TEXT;
2288 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2289 WHERE place_id = in_place_id
2290 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2292 IF for_place_id IS NULL THEN
2293 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2294 WHERE place_id = in_place_id
2295 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2298 IF for_place_id IS NULL THEN
2299 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2300 WHERE place_id = in_place_id and rank_address = 30
2301 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2304 IF for_place_id IS NULL THEN
2305 for_place_id := in_place_id;
2306 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2307 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2310 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2313 hadcountry := false;
2315 select placex.place_id, osm_type, osm_id,
2316 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2317 class, type, admin_level, true as fromarea, true as isaddress,
2318 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2319 0 as distance, calculated_country_code
2321 where place_id = for_place_id
2323 --RAISE WARNING '%',location;
2324 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2325 searchcountrycode := location.calculated_country_code;
2327 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2328 location.isaddress := FALSE;
2330 IF location.rank_address = 4 AND location.isaddress THEN
2333 IF location.rank_address < 4 AND NOT hadcountry THEN
2334 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2335 IF countryname IS NOT NULL THEN
2336 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2337 RETURN NEXT countrylocation;
2340 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2341 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2342 location.distance)::addressline;
2343 RETURN NEXT countrylocation;
2344 found := location.rank_address;
2348 select placex.place_id, osm_type, osm_id,
2349 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2350 class, type, admin_level, fromarea, isaddress,
2351 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,
2352 distance,calculated_country_code
2353 from place_addressline join placex on (address_place_id = placex.place_id)
2354 where place_addressline.place_id = for_place_id
2355 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2356 and address_place_id != for_place_id
2357 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2358 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2360 --RAISE WARNING '%',location;
2361 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2362 searchcountrycode := location.calculated_country_code;
2364 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2365 location.isaddress := FALSE;
2367 IF location.rank_address = 4 AND location.isaddress THEN
2370 IF location.rank_address < 4 AND NOT hadcountry THEN
2371 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2372 IF countryname IS NOT NULL THEN
2373 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2374 RETURN NEXT countrylocation;
2377 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2378 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2379 location.distance)::addressline;
2380 RETURN NEXT countrylocation;
2381 found := location.rank_address;
2385 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2386 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2387 IF countryname IS NOT NULL THEN
2388 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2389 RETURN NEXT location;
2393 IF searchcountrycode IS NOT NULL THEN
2394 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2395 RETURN NEXT location;
2398 IF searchhousename IS NOT NULL THEN
2399 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2400 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2401 RETURN NEXT location;
2404 IF searchhousenumber IS NOT NULL THEN
2405 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2406 RETURN NEXT location;
2409 IF searchpostcode IS NOT NULL THEN
2410 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2411 RETURN NEXT location;
2419 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2422 result place_boundingbox;
2423 numfeatures integer;
2425 select * from place_boundingbox into result where place_id = search_place_id;
2426 IF result.place_id IS NULL THEN
2427 -- remove isaddress = true because if there is a matching polygon it always wins
2428 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2429 insert into place_boundingbox select place_id,
2430 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2431 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2432 numfeatures, ST_Area(geometry),
2433 geometry as area from location_area where place_id = search_place_id;
2434 select * from place_boundingbox into result where place_id = search_place_id;
2436 IF result.place_id IS NULL THEN
2438 insert into place_boundingbox select address_place_id,
2439 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2440 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2441 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2442 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2443 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)
2444 where address_place_id = search_place_id
2445 -- and (isaddress = true OR place_id = search_place_id)
2446 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2447 group by address_place_id limit 1;
2448 select * from place_boundingbox into result where place_id = search_place_id;
2455 -- don't do the operation if it would be slow
2456 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2459 result place_boundingbox;
2460 numfeatures integer;
2463 select * from place_boundingbox into result where place_id = search_place_id;
2464 IF result IS NULL AND rank > 14 THEN
2465 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2466 insert into place_boundingbox select place_id,
2467 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2468 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2469 numfeatures, ST_Area(geometry),
2470 geometry as area from location_area where place_id = search_place_id;
2471 select * from place_boundingbox into result where place_id = search_place_id;
2473 IF result IS NULL THEN
2474 select rank_search from placex where place_id = search_place_id into rank;
2477 insert into place_boundingbox select address_place_id,
2478 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2479 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2480 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2481 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2482 from place_addressline join placex using (place_id)
2483 where address_place_id = search_place_id
2484 and (isaddress = true OR place_id = search_place_id)
2485 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2486 group by address_place_id limit 1;
2487 select * from place_boundingbox into result where place_id = search_place_id;
2495 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2498 result place_boundingbox;
2499 numfeatures integer;
2503 housenumber = place.housenumber,
2504 street = place.street,
2506 postcode = place.postcode,
2507 country_code = place.country_code,
2508 parent_place_id = null
2510 where placex.place_id = search_place_id
2511 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2512 and place.class = placex.class and place.type = placex.type;
2513 update placex set indexed_status = 2 where place_id = search_place_id;
2514 update placex set indexed_status = 0 where place_id = search_place_id;
2520 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2526 ELSEIF rank < 4 THEN
2528 ELSEIF rank < 8 THEN
2530 ELSEIF rank < 12 THEN
2532 ELSEIF rank < 16 THEN
2534 ELSEIF rank = 16 THEN
2536 ELSEIF rank = 17 THEN
2537 RETURN 'Town / Island';
2538 ELSEIF rank = 18 THEN
2539 RETURN 'Village / Hamlet';
2540 ELSEIF rank = 20 THEN
2542 ELSEIF rank = 21 THEN
2543 RETURN 'Postcode Area';
2544 ELSEIF rank = 22 THEN
2545 RETURN 'Croft / Farm / Locality / Islet';
2546 ELSEIF rank = 23 THEN
2547 RETURN 'Postcode Area';
2548 ELSEIF rank = 25 THEN
2549 RETURN 'Postcode Point';
2550 ELSEIF rank = 26 THEN
2551 RETURN 'Street / Major Landmark';
2552 ELSEIF rank = 27 THEN
2553 RETURN 'Minory Street / Path';
2554 ELSEIF rank = 28 THEN
2555 RETURN 'House / Building';
2557 RETURN 'Other: '||rank;
2564 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2570 ELSEIF rank < 2 THEN
2572 ELSEIF rank < 4 THEN
2574 ELSEIF rank = 5 THEN
2576 ELSEIF rank < 8 THEN
2578 ELSEIF rank < 12 THEN
2580 ELSEIF rank < 16 THEN
2582 ELSEIF rank = 16 THEN
2584 ELSEIF rank = 17 THEN
2585 RETURN 'Town / Village / Hamlet';
2586 ELSEIF rank = 20 THEN
2588 ELSEIF rank = 21 THEN
2589 RETURN 'Postcode Area';
2590 ELSEIF rank = 22 THEN
2591 RETURN 'Croft / Farm / Locality / Islet';
2592 ELSEIF rank = 23 THEN
2593 RETURN 'Postcode Area';
2594 ELSEIF rank = 25 THEN
2595 RETURN 'Postcode Point';
2596 ELSEIF rank = 26 THEN
2597 RETURN 'Street / Major Landmark';
2598 ELSEIF rank = 27 THEN
2599 RETURN 'Minory Street / Path';
2600 ELSEIF rank = 28 THEN
2601 RETURN 'House / Building';
2603 RETURN 'Other: '||rank;
2610 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2617 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2618 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2625 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2633 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2635 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2636 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2638 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2646 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2647 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2652 place_centroid GEOMETRY;
2653 out_partition INTEGER;
2654 out_parent_place_id BIGINT;
2656 address_street_word_id INTEGER;
2661 place_centroid := ST_Centroid(pointgeo);
2662 out_partition := get_partition(place_centroid, in_countrycode);
2663 out_parent_place_id := null;
2665 address_street_word_id := get_name_id(make_standard_name(in_street));
2666 IF address_street_word_id IS NOT NULL THEN
2667 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2668 out_parent_place_id := location.place_id;
2672 IF out_parent_place_id IS NULL THEN
2673 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2674 out_parent_place_id := location.place_id;
2678 out_postcode := in_postcode;
2679 IF out_postcode IS NULL THEN
2680 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2682 IF out_postcode IS NULL THEN
2683 out_postcode := getNearestPostcode(out_partition, place_centroid);
2687 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2688 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2689 newpoints := newpoints + 1;
2696 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2703 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2704 IF members[i+1] = member THEN
2705 result := result || members[i];
2714 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2720 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2721 IF members[i+1] = ANY(memberLabels) THEN
2722 RETURN NEXT members[i];
2731 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2732 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2734 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2735 SELECT CASE WHEN length(r.m[1]) = 1 THEN encode(convert_to(r.m[1], 'SQL_ASCII'), 'hex') ELSE substring(r.m[1] from 2 for 2) END
2736 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2737 ), '') AS bytea), 'UTF8');
2739 LANGUAGE SQL IMMUTABLE STRICT;
2741 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2745 RETURN decode_url_part(p);
2747 WHEN others THEN return null;
2750 LANGUAGE plpgsql IMMUTABLE;
2752 DROP TYPE wikipedia_article_match CASCADE;
2753 create type wikipedia_article_match as (
2759 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2765 wiki_article_title TEXT;
2766 wiki_article_language TEXT;
2767 result wikipedia_article_match;
2769 langs := ARRAY['english','country','ar','bg','ca','cs','da','de','en','es','eo','eu','fa','fr','ko','hi','hr','id','it','he','lt','hu','ms','nl','ja','no','pl','pt','kk','ro','ru','sk','sl','sr','fi','sv','tr','uk','vi','vo','war','zh'];
2771 WHILE langs[i] IS NOT NULL LOOP
2772 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2773 IF wiki_article is not null THEN
2774 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2775 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2776 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2777 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2778 wiki_article := replace(wiki_article,' ','_');
2779 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2780 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2781 wiki_article_title := trim(wiki_article);
2782 wiki_article_language := CASE WHEN langs[i] = 'english' THEN 'en' WHEN langs[i] = 'country' THEN get_country_language_code(country_code) ELSE langs[i] END;
2784 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2787 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2788 from wikipedia_article
2789 where language = wiki_article_language and
2790 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2792 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2793 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2794 where wikipedia_redirect.language = wiki_article_language and
2795 (from_title = wiki_article_title OR from_title = catch_decode_url_part(wiki_article_title) OR from_title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2796 order by importance desc limit 1 INTO result;
2798 IF result.language is not null THEN
2809 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2810 RETURNS SETOF GEOMETRY
2824 remainingdepth INTEGER;
2829 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2831 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2832 RETURN NEXT geometry;
2836 remainingdepth := maxdepth - 1;
2837 area := ST_AREA(geometry);
2838 IF remainingdepth < 1 OR area < maxarea THEN
2839 RETURN NEXT geometry;
2843 xmin := st_xmin(geometry);
2844 xmax := st_xmax(geometry);
2845 ymin := st_ymin(geometry);
2846 ymax := st_ymax(geometry);
2847 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2849 -- if the geometry completely covers the box don't bother to slice any more
2850 IF ST_AREA(secbox) = area THEN
2851 RETURN NEXT geometry;
2855 xmid := (xmin+xmax)/2;
2856 ymid := (ymin+ymax)/2;
2859 FOR seg IN 1..4 LOOP
2862 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2865 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2868 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2871 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2874 IF st_intersects(geometry, secbox) THEN
2875 secgeo := st_intersection(geometry, secbox);
2876 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2877 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2878 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2880 RETURN NEXT geo.geom;
2892 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2893 RETURNS SETOF GEOMETRY
2898 -- 10000000000 is ~~ 1x1 degree
2899 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2900 RETURN NEXT geo.geom;