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 make_keywords(src HSTORE) RETURNS INTEGER[]
309 result := '{}'::INTEGER[];
311 FOR item IN SELECT (each(src)).* LOOP
313 s := make_standard_name(item.value);
315 w := getorcreate_name_id(s, item.value);
317 IF not(ARRAY[w] <@ result) THEN
318 result := result || w;
321 words := string_to_array(s, ' ');
322 IF array_upper(words, 1) IS NOT NULL THEN
323 FOR j IN 1..array_upper(words, 1) LOOP
324 IF (words[j] != '') THEN
325 w = getorcreate_word_id(words[j]);
326 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
327 result := result || w;
333 words := regexp_split_to_array(item.value, E'[,;()]');
334 IF array_upper(words, 1) != 1 THEN
335 FOR j IN 1..array_upper(words, 1) LOOP
336 s := make_standard_name(words[j]);
338 w := getorcreate_word_id(s);
339 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
340 result := result || w;
346 s := regexp_replace(item.value, '市$', '');
347 IF s != item.value THEN
348 s := make_standard_name(s);
350 w := getorcreate_name_id(s, item.value);
351 IF NOT (ARRAY[w] <@ result) THEN
352 result := result || w;
362 LANGUAGE plpgsql IMMUTABLE;
364 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
374 result := '{}'::INTEGER[];
376 s := make_standard_name(src);
377 w := getorcreate_name_id(s, src);
379 IF NOT (ARRAY[w] <@ result) THEN
380 result := result || w;
383 words := string_to_array(s, ' ');
384 IF array_upper(words, 1) IS NOT NULL THEN
385 FOR j IN 1..array_upper(words, 1) LOOP
386 IF (words[j] != '') THEN
387 w = getorcreate_word_id(words[j]);
388 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
389 result := result || w;
395 words := regexp_split_to_array(src, E'[,;()]');
396 IF array_upper(words, 1) != 1 THEN
397 FOR j IN 1..array_upper(words, 1) LOOP
398 s := make_standard_name(words[j]);
400 w := getorcreate_word_id(s);
401 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
402 result := result || w;
408 s := regexp_replace(src, '市$', '');
410 s := make_standard_name(s);
412 w := getorcreate_name_id(s, src);
413 IF NOT (ARRAY[w] <@ result) THEN
414 result := result || w;
422 LANGUAGE plpgsql IMMUTABLE;
424 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
431 IF (wordscores is null OR words is null) THEN
436 FOR idxword in 1 .. array_upper(words, 1) LOOP
437 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
438 IF wordscores[idxscores].word = words[idxword] THEN
439 result := result + wordscores[idxscores].score;
447 LANGUAGE plpgsql IMMUTABLE;
449 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
452 place_centre GEOMETRY;
455 place_centre := ST_PointOnSurface(place);
457 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
459 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
461 -- Try for OSM fallback data
462 -- The order is to deal with places like HongKong that are 'states' within another polygon
463 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
465 RETURN nearcountry.country_code;
468 -- Try for a OSM polygon
469 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
471 RETURN nearcountry.country_code;
474 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
476 -- Natural earth data
477 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
479 RETURN nearcountry.country_code;
482 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
485 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
487 RETURN nearcountry.country_code;
490 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
492 -- Natural earth data
493 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
495 RETURN nearcountry.country_code;
498 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
499 -- FOR nearcountry IN select country_code from country where st_covers(geometry, place_centre) limit 1
501 -- RETURN nearcountry.country_code;
504 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
506 -- Still not in a country - try nearest within ~12 miles of a country
507 -- FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
508 -- order by st_distance(geometry, place) limit 1
510 -- RETURN nearcountry.country_code;
516 LANGUAGE plpgsql IMMUTABLE;
518 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
523 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
525 RETURN nearcountry.country_code;
527 RETURN get_country_code(place);
530 LANGUAGE plpgsql IMMUTABLE;
532 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
537 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
539 RETURN lower(nearcountry.country_default_language_code);
544 LANGUAGE plpgsql IMMUTABLE;
546 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
549 place_centre GEOMETRY;
552 FOR nearcountry IN select partition from country_name where country_code = in_country_code
554 RETURN nearcountry.partition;
559 LANGUAGE plpgsql IMMUTABLE;
561 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
565 DELETE FROM location_area where place_id = OLD_place_id;
566 -- TODO:location_area
572 CREATE OR REPLACE FUNCTION add_location(
574 country_code varchar(2),
578 rank_address INTEGER,
593 IF rank_search > 25 THEN
594 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
597 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
599 x := deleteLocationArea(partition, place_id);
602 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
605 centroid := ST_Centroid(geometry);
607 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
608 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
611 ELSEIF rank_search < 26 THEN
614 IF rank_address = 0 THEN
616 ELSEIF rank_search <= 14 THEN
618 ELSEIF rank_search <= 15 THEN
620 ELSEIF rank_search <= 16 THEN
622 ELSEIF rank_search <= 17 THEN
624 ELSEIF rank_search <= 21 THEN
626 ELSEIF rank_search = 25 THEN
630 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
632 secgeo := ST_Buffer(geometry, diameter);
633 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
638 secgeo := ST_Buffer(geometry, 0.0002);
639 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
642 secgeo := ST_Buffer(geometry, 0.001);
643 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
652 CREATE OR REPLACE FUNCTION update_location(
655 place_country_code varchar(2),
658 rank_address INTEGER,
666 b := deleteLocationArea(partition, place_id);
667 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
668 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
673 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
684 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
685 FOR childplace IN select * from search_name,place_addressline
686 where address_place_id = parent_place_id
687 and search_name.place_id = place_addressline.place_id
689 delete from search_name where place_id = childplace.place_id;
690 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
691 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
693 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
694 childplace.name_vector := childplace.name_vector || to_add;
696 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
697 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
698 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
706 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
709 newkeywords INTEGER[];
710 addedkeywords INTEGER[];
711 removedkeywords INTEGER[];
715 newkeywords := make_keywords(name);
716 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
717 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
718 where place_id = OLD_place_id into addedkeywords, removedkeywords;
720 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
722 IF #removedkeywords > 0 THEN
723 -- abort due to tokens removed
727 IF #addedkeywords > 0 THEN
728 -- short circuit - no changes
732 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
733 RETURN search_name_add_words(OLD_place_id, addedkeywords);
739 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
751 orginalstartnumber INTEGER;
752 originalnumberrange INTEGER;
755 search_place_id BIGINT;
758 havefirstpoint BOOLEAN;
762 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
764 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
765 select nodes from planet_osm_ways where id = wayid INTO waynodes;
766 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
767 IF array_upper(waynodes, 1) IS NOT NULL THEN
769 havefirstpoint := false;
771 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
773 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
774 IF search_place_id IS NULL THEN
775 -- null record of right type
776 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
777 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
778 IF nextnode.geometry IS NULL THEN
779 -- we don't have any information about this point, most likely
780 -- because an excerpt was updated and the node never imported
781 -- because the interpolation is outside the region of the excerpt.
786 select * from placex where place_id = search_place_id INTO nextnode;
789 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
791 IF havefirstpoint THEN
793 -- add point to the line string
794 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
795 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
797 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
799 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
801 IF startnumber != endnumber THEN
803 linestr := linestr || ')';
804 --RAISE WARNING 'linestr %',linestr;
805 linegeo := ST_GeomFromText(linestr,4326);
806 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
807 IF (startnumber > endnumber) THEN
808 housenum := endnumber;
809 endnumber := startnumber;
810 startnumber := housenum;
811 linegeo := ST_Reverse(linegeo);
813 orginalstartnumber := startnumber;
814 originalnumberrange := endnumber - startnumber;
816 -- Too much broken data worldwide for this test to be worth using
817 -- IF originalnumberrange > 500 THEN
818 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
821 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
822 startnumber := startnumber + 1;
825 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
826 startnumber := startnumber + 2;
828 ELSE -- everything else assumed to be 'all'
829 startnumber := startnumber + 1;
833 endnumber := endnumber - 1;
834 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
835 FOR housenum IN startnumber..endnumber BY stepsize LOOP
836 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
837 -- ideally postcodes should move up to the way
838 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
839 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
840 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
841 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));
842 newpoints := newpoints + 1;
843 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
846 havefirstpoint := false;
850 IF NOT havefirstpoint THEN
851 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
852 IF startnumber IS NOT NULL AND startnumber > 0 THEN
853 havefirstpoint := true;
854 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
855 prevnode := nextnode;
857 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
863 --RAISE WARNING 'interpolation points % ',newpoints;
870 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
876 country_code VARCHAR(2);
877 default_language VARCHAR(10);
881 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
884 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
885 -- RAISE WARNING 'bad highway %',NEW.osm_id;
888 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
889 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
893 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
894 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
895 RAISE WARNING 'invalid geometry %',NEW.osm_id;
899 IF NEW.osm_type = 'R' THEN
900 -- invalid multipolygons can crash postgis, don't even bother to try!
903 NEW.geometry := ST_buffer(NEW.geometry,0);
904 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
905 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
910 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
912 NEW.place_id := nextval('seq_place');
913 NEW.indexed_status := 1; --STATUS_NEW
915 NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
917 NEW.partition := get_partition(NEW.geometry, NEW.calculated_country_code);
918 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
920 -- copy 'name' to or from the default language (if there is a default language)
921 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
922 default_language := get_country_language_code(NEW.calculated_country_code);
923 IF default_language IS NOT NULL THEN
924 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
925 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
926 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
927 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
932 IF NEW.admin_level > 15 THEN
933 NEW.admin_level := 15;
936 IF NEW.housenumber IS NOT NULL THEN
937 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
940 IF NEW.osm_type = 'X' THEN
941 -- E'X'ternal records should already be in the right format so do nothing
943 NEW.rank_search := 30;
944 NEW.rank_address := NEW.rank_search;
946 -- By doing in postgres we have the country available to us - currently only used for postcode
947 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
949 IF NEW.postcode IS NULL THEN
950 -- most likely just a part of a multipolygon postcode boundary, throw it away
954 NEW.name := 'ref'=>NEW.postcode;
956 IF NEW.calculated_country_code = 'gb' THEN
958 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
959 NEW.rank_search := 25;
960 NEW.rank_address := 5;
961 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
962 NEW.rank_search := 23;
963 NEW.rank_address := 5;
964 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
965 NEW.rank_search := 21;
966 NEW.rank_address := 5;
969 ELSEIF NEW.calculated_country_code = 'de' THEN
971 IF NEW.postcode ~ '^([0-9]{5})$' THEN
972 NEW.rank_search := 21;
973 NEW.rank_address := 11;
977 -- Guess at the postcode format and coverage (!)
978 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
979 NEW.rank_search := 21;
980 NEW.rank_address := 11;
982 -- Does it look splitable into and area and local code?
983 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
985 IF postcode IS NOT NULL THEN
986 NEW.rank_search := 25;
987 NEW.rank_address := 11;
988 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
989 NEW.rank_search := 21;
990 NEW.rank_address := 11;
995 ELSEIF NEW.class = 'place' THEN
996 IF NEW.type in ('continent') THEN
997 NEW.rank_search := 2;
998 NEW.rank_address := NEW.rank_search;
999 NEW.calculated_country_code := NULL;
1000 ELSEIF NEW.type in ('sea') THEN
1001 NEW.rank_search := 2;
1002 NEW.rank_address := 0;
1003 NEW.calculated_country_code := NULL;
1004 ELSEIF NEW.type in ('country') THEN
1005 NEW.rank_search := 4;
1006 NEW.rank_address := NEW.rank_search;
1007 ELSEIF NEW.type in ('state') THEN
1008 NEW.rank_search := 8;
1009 NEW.rank_address := NEW.rank_search;
1010 ELSEIF NEW.type in ('region') THEN
1011 NEW.rank_search := 18; -- dropped from previous value of 10
1012 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1013 ELSEIF NEW.type in ('county') THEN
1014 NEW.rank_search := 12;
1015 NEW.rank_address := NEW.rank_search;
1016 ELSEIF NEW.type in ('city') THEN
1017 NEW.rank_search := 16;
1018 NEW.rank_address := NEW.rank_search;
1019 ELSEIF NEW.type in ('island') THEN
1020 NEW.rank_search := 17;
1021 NEW.rank_address := 0;
1022 ELSEIF NEW.type in ('town') THEN
1023 NEW.rank_search := 18;
1024 NEW.rank_address := 16;
1025 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1026 NEW.rank_search := 19;
1027 NEW.rank_address := 16;
1028 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1029 NEW.rank_search := 18;
1030 NEW.rank_address := 17;
1031 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1032 NEW.rank_search := 17;
1033 NEW.rank_address := 18;
1034 ELSEIF NEW.type in ('moor') THEN
1035 NEW.rank_search := 17;
1036 NEW.rank_address := 0;
1037 ELSEIF NEW.type in ('national_park') THEN
1038 NEW.rank_search := 18;
1039 NEW.rank_address := 18;
1040 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1041 NEW.rank_search := 20;
1042 NEW.rank_address := NEW.rank_search;
1043 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1044 NEW.rank_search := 20;
1045 NEW.rank_address := 0;
1046 -- Irish townlands, tagged as place=locality and locality=townland
1047 IF (NEW.extratags -> 'locality') = 'townland' THEN
1048 NEW.rank_address := 20;
1050 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1051 NEW.rank_search := 22;
1052 NEW.rank_address := 22;
1053 ELSEIF NEW.type in ('airport','street') THEN
1054 NEW.rank_search := 26;
1055 NEW.rank_address := NEW.rank_search;
1056 ELSEIF NEW.type in ('house','building') THEN
1057 NEW.rank_search := 30;
1058 NEW.rank_address := NEW.rank_search;
1059 ELSEIF NEW.type in ('houses') THEN
1060 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1061 -- insert new point into place for each derived building
1062 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1063 NEW.rank_search := 28;
1064 NEW.rank_address := 0;
1067 ELSEIF NEW.class = 'boundary' THEN
1068 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1069 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1072 NEW.rank_search := NEW.admin_level * 2;
1073 NEW.rank_address := NEW.rank_search;
1074 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1075 NEW.rank_search := 22;
1076 NEW.rank_address := NEW.rank_search;
1077 -- any feature more than 5 square miles is probably worth indexing
1078 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1079 NEW.rank_search := 22;
1080 NEW.rank_address := NEW.rank_search;
1081 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1082 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1083 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1085 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1087 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1089 ELSEIF NEW.class = 'waterway' THEN
1090 NEW.rank_address := 17;
1091 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
1092 NEW.rank_search := 27;
1093 NEW.rank_address := NEW.rank_search;
1094 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1095 NEW.rank_search := 26;
1096 NEW.rank_address := NEW.rank_search;
1097 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1098 NEW.rank_search := 4;
1099 NEW.rank_address := NEW.rank_search;
1100 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1102 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1103 NEW.rank_search := 18;
1104 NEW.rank_address := 0;
1109 IF NEW.rank_search > 30 THEN
1110 NEW.rank_search := 30;
1113 IF NEW.rank_address > 30 THEN
1114 NEW.rank_address := 30;
1117 IF (NEW.extratags -> 'capital') = 'yes' THEN
1118 NEW.rank_search := NEW.rank_search - 1;
1121 -- a country code make no sense below rank 4 (country)
1122 IF NEW.rank_address < 4 THEN
1123 NEW.calculated_country_code := NULL;
1126 -- Block import below rank 22
1127 -- IF NEW.rank_search > 22 THEN
1131 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1133 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1135 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1136 -- Performance: We just can't handle re-indexing for country level changes
1137 IF st_area(NEW.geometry) < 1 THEN
1138 -- mark items within the geometry for re-indexing
1139 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1141 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1142 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1143 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);
1144 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1145 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);
1148 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1150 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1151 IF NEW.type='postcode' THEN
1153 ELSEIF NEW.rank_search < 16 THEN
1155 ELSEIF NEW.rank_search < 18 THEN
1157 ELSEIF NEW.rank_search < 20 THEN
1159 ELSEIF NEW.rank_search = 21 THEN
1161 ELSEIF NEW.rank_search < 24 THEN
1163 ELSEIF NEW.rank_search < 26 THEN
1164 diameter := 0.002; -- 100 to 200 meters
1165 ELSEIF NEW.rank_search < 28 THEN
1166 diameter := 0.001; -- 50 to 100 meters
1168 IF diameter > 0 THEN
1169 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1170 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);
1175 -- add to tables for special search
1176 -- Note: won't work on initial import because the classtype tables
1177 -- do not yet exist. It won't hurt either.
1178 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1179 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1181 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1182 USING NEW.place_id, ST_Centroid(NEW.geometry);
1186 -- IF NEW.rank_search < 26 THEN
1187 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1196 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1201 place_centroid GEOMETRY;
1203 search_maxdistance FLOAT[];
1204 search_mindistance FLOAT[];
1205 address_havelevel BOOLEAN[];
1206 -- search_scores wordscore[];
1207 -- search_scores_pos INTEGER;
1214 relation_members TEXT[];
1216 linkedplacex RECORD;
1217 search_diameter FLOAT;
1218 search_prevdiameter FLOAT;
1219 search_maxrank INTEGER;
1220 address_maxrank INTEGER;
1221 address_street_word_id INTEGER;
1222 parent_place_id_rank BIGINT;
1227 location_rank_search INTEGER;
1228 location_distance FLOAT;
1229 location_parent GEOMETRY;
1230 location_isaddress BOOLEAN;
1234 default_language TEXT;
1235 name_vector INTEGER[];
1236 nameaddress_vector INTEGER[];
1238 linked_node_id BIGINT;
1244 IF OLD.indexed_status = 100 THEN
1245 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1246 delete from placex where place_id = OLD.place_id;
1250 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 OR NEW.linked_place_id is not null THEN
1254 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1256 --RAISE WARNING '%',NEW.place_id;
1257 --RAISE WARNING '%', NEW;
1259 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1260 -- Silently do nothing
1264 IF OLD.indexed_status != 0 THEN
1265 --DEBUG: RAISE WARNING 'placex_update_0 % %',NEW.osm_type,NEW.osm_id;
1267 NEW.indexed_date = now();
1269 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1270 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1274 IF OLD.indexed_status > 0 THEN
1275 result := deleteSearchName(NEW.partition, NEW.place_id);
1276 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1277 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1278 result := deleteRoad(NEW.partition, NEW.place_id);
1279 result := deleteLocationArea(NEW.partition, NEW.place_id);
1280 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1283 -- Speed up searches - just use the centroid of the feature
1284 -- cheaper but less acurate
1285 place_centroid := ST_PointOnSurface(NEW.geometry);
1286 NEW.centroid := null;
1288 -- reclaculate country and partition
1289 IF NEW.rank_search >= 4 THEN
1290 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1291 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1293 NEW.calculated_country_code := NULL;
1295 NEW.partition := get_partition(place_centroid, NEW.calculated_country_code);
1296 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1298 -- Adding ourselves to the list simplifies address calculations later
1299 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1301 -- What level are we searching from
1302 search_maxrank := NEW.rank_search;
1304 -- Thought this wasn't needed but when we add new languages to the country_name table
1305 -- we need to update the existing names
1306 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1307 default_language := get_country_language_code(NEW.calculated_country_code);
1308 IF default_language IS NOT NULL THEN
1309 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1310 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1311 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1312 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1317 -- Initialise the name vector using our name
1318 name_vector := make_keywords(NEW.name);
1319 nameaddress_vector := '{}'::int[];
1321 -- some tag combinations add a special id for search
1322 tagpairid := get_tagpair(NEW.class,NEW.type);
1323 IF tagpairid IS NOT NULL THEN
1324 name_vector := name_vector + tagpairid;
1328 address_havelevel[i] := false;
1331 NEW.importance := null;
1332 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1333 IF NEW.importance IS NULL THEN
1334 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;
1337 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1339 -- For low level elements we inherit from our parent road
1340 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1342 --RAISE WARNING 'finding street for %', NEW;
1344 NEW.parent_place_id := null;
1346 -- to do that we have to find our parent road
1347 -- Copy data from linked items (points on ways, addr:street links, relations)
1348 -- Note that addr:street links can only be indexed once the street itself is indexed
1349 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1351 -- Is this node part of a relation?
1352 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1354 -- At the moment we only process one type of relation - associatedStreet
1355 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1356 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1357 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1358 --RAISE WARNING 'node in relation %',relation;
1359 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1360 and rank_search = 26 INTO NEW.parent_place_id;
1366 --RAISE WARNING 'x1';
1367 -- Is this node part of a way?
1368 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1369 --RAISE WARNING '%', way;
1370 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1372 --RAISE WARNING '%', location;
1373 -- Way IS a road then we are on it - that must be our road
1374 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1375 --RAISE WARNING 'node in way that is a street %',location;
1376 NEW.parent_place_id := location.place_id;
1379 -- Is the WAY part of a relation
1380 IF NEW.parent_place_id IS NULL THEN
1381 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1383 -- At the moment we only process one type of relation - associatedStreet
1384 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1385 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1386 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1387 --RAISE WARNING 'node in way that is in a relation %',relation;
1388 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1389 and rank_search = 26 INTO NEW.parent_place_id;
1396 -- If the way contains an explicit name of a street copy it
1397 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1398 --RAISE WARNING 'node in way that has a streetname %',location;
1399 NEW.street := location.street;
1402 -- If this way is a street interpolation line then it is probably as good as we are going to get
1403 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1404 -- Try and find a way that is close roughly parellel to this line
1405 FOR relation IN SELECT place_id FROM placex
1406 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1407 and st_geometrytype(location.geometry) in ('ST_LineString')
1408 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1409 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1410 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1412 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1413 NEW.parent_place_id := relation.place_id;
1422 --RAISE WARNING 'x2';
1424 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1425 -- Is this way part of a relation?
1426 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1428 -- At the moment we only process one type of relation - associatedStreet
1429 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1430 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1431 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1432 --RAISE WARNING 'way that is in a relation %',relation;
1433 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1434 and rank_search = 26 INTO NEW.parent_place_id;
1441 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1443 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1444 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1445 IF address_street_word_id IS NOT NULL THEN
1446 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1447 NEW.parent_place_id := location.place_id;
1452 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1453 -- Still nothing, just use the nearest road
1454 IF NEW.parent_place_id IS NULL THEN
1455 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1456 NEW.parent_place_id := location.place_id;
1461 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1463 -- If we didn't find any road fallback to standard method
1464 IF NEW.parent_place_id IS NOT NULL THEN
1466 -- Add the street to the address as zero distance to force to front of list
1467 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1468 address_havelevel[26] := true;
1470 -- Import address details from parent, reclculating distance in process
1471 -- 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
1472 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1473 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1475 -- Get the details of the parent road
1476 select * from search_name where place_id = NEW.parent_place_id INTO location;
1477 NEW.calculated_country_code := location.country_code;
1479 --RAISE WARNING '%', NEW.name;
1480 -- If there is no name it isn't searchable, don't bother to create a search record
1481 IF NEW.name is NULL THEN
1485 -- Merge address from parent
1486 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1488 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1489 -- Just be happy with inheriting from parent road only
1491 IF NEW.rank_search <= 25 THEN
1492 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1495 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);
1502 -- RAISE WARNING ' INDEXING Started:';
1503 -- RAISE WARNING ' INDEXING: %',NEW;
1505 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1507 -- see if we have any special relation members
1508 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1510 -- RAISE WARNING 'get_osm_rel_members, label';
1511 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1513 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1514 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1516 -- If we don't already have one use this as the centre point of the geometry
1517 IF NEW.centroid IS NULL THEN
1518 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1521 -- merge in the label name, re-init word vector
1522 IF NOT linkedPlacex.name IS NULL THEN
1523 NEW.name := linkedPlacex.name || NEW.name;
1524 name_vector := make_keywords(NEW.name);
1527 -- merge in extra tags
1528 IF NOT linkedPlacex.extratags IS NULL THEN
1529 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1532 -- mark the linked place (excludes from search results)
1533 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1539 IF NEW.centroid IS NULL THEN
1541 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1543 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1544 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1546 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1547 -- But that can be fixed by explicitly setting the label in the data
1548 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1549 AND NEW.rank_address = linkedPlacex.rank_address THEN
1552 -- If we don't already have one use this as the centre point of the geometry
1553 IF NEW.centroid IS NULL THEN
1554 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1557 -- merge in the name, re-init word vector
1558 IF NOT linkedPlacex.name IS NULL THEN
1559 NEW.name := linkedPlacex.name || NEW.name;
1560 name_vector := make_keywords(NEW.name);
1563 -- merge in extra tags
1564 IF NOT linkedPlacex.extratags IS NULL THEN
1565 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1568 -- mark the linked place (excludes from search results)
1569 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1571 -- keep a note of the node id in case we need it for wikipedia in a bit
1572 linked_node_id := linkedPlacex.osm_id;
1581 -- not found one yet? how about doing a name search
1582 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1584 FOR linkedPlacex IN select placex.* from placex WHERE
1585 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1586 AND placex.rank_address = NEW.rank_address
1587 AND placex.place_id != NEW.place_id
1588 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1589 AND st_covers(NEW.geometry, placex.geometry)
1592 -- If we don't already have one use this as the centre point of the geometry
1593 IF NEW.centroid IS NULL THEN
1594 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1597 -- merge in the name, re-init word vector
1598 NEW.name := linkedPlacex.name || NEW.name;
1599 name_vector := make_keywords(NEW.name);
1601 -- merge in extra tags
1602 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1604 -- mark the linked place (excludes from search results)
1605 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1607 -- keep a note of the node id in case we need it for wikipedia in a bit
1608 linked_node_id := linkedPlacex.osm_id;
1612 IF NEW.centroid IS NOT NULL THEN
1613 place_centroid := NEW.centroid;
1616 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1617 IF NEW.importance is null THEN
1618 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1620 -- Still null? how about looking it up by the node id
1621 IF NEW.importance IS NULL THEN
1622 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;
1627 NEW.parent_place_id = 0;
1628 parent_place_id_rank = 0;
1630 -- convert isin to array of tokenids
1631 isin_tokens := '{}'::int[];
1632 IF NEW.isin IS NOT NULL THEN
1633 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1634 IF array_upper(isin, 1) IS NOT NULL THEN
1635 FOR i IN 1..array_upper(isin, 1) LOOP
1636 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1637 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1638 isin_tokens := isin_tokens || address_street_word_id;
1643 IF NEW.postcode IS NOT NULL THEN
1644 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1645 IF array_upper(isin, 1) IS NOT NULL THEN
1646 FOR i IN 1..array_upper(isin, 1) LOOP
1647 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1648 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1649 isin_tokens := isin_tokens || address_street_word_id;
1654 -- RAISE WARNING 'ISIN: %', isin_tokens;
1656 -- Process area matches
1657 location_rank_search := 0;
1658 location_distance := 0;
1659 location_parent := NULL;
1660 -- added ourself as address already
1661 address_havelevel[NEW.rank_address] := true;
1662 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1663 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1665 --RAISE WARNING ' AREA: %',location;
1667 IF location.rank_address != location_rank_search THEN
1668 location_rank_search := location.rank_address;
1669 location_distance := location.distance * 1.5;
1672 IF location.distance < location_distance OR NOT location.isguess THEN
1674 location_isaddress := NOT address_havelevel[location.rank_address];
1675 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1676 location_isaddress := ST_Contains(location_parent,location.centroid);
1679 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1680 -- Add it to the list of search terms
1681 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1682 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1684 IF location_isaddress THEN
1685 address_havelevel[location.rank_address] := true;
1686 IF NOT location.isguess THEN
1687 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1691 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1693 IF location.rank_address > parent_place_id_rank THEN
1694 NEW.parent_place_id = location.place_id;
1695 parent_place_id_rank = location.rank_address;
1702 -- try using the isin value to find parent places
1703 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1704 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1705 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1707 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1709 --RAISE WARNING ' ISIN: %',location;
1711 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1712 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1713 address_havelevel[location.rank_address] := true;
1715 IF location.rank_address > parent_place_id_rank THEN
1716 NEW.parent_place_id = location.place_id;
1717 parent_place_id_rank = location.rank_address;
1725 -- for long ways we should add search terms for the entire length
1726 IF st_length(NEW.geometry) > 0.05 THEN
1728 location_rank_search := 0;
1729 location_distance := 0;
1731 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1733 IF location.rank_address != location_rank_search THEN
1734 location_rank_search := location.rank_address;
1735 location_distance := location.distance * 1.5;
1738 IF location.distance < location_distance THEN
1740 -- Add it to the list of search terms
1741 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1742 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1750 -- if we have a name add this to the name search table
1751 IF NEW.name IS NOT NULL THEN
1753 IF NEW.rank_search <= 25 THEN
1754 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1757 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1758 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1761 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);
1763 -- 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);
1766 -- If we've not managed to pick up a better one - default centroid
1767 IF NEW.centroid IS NULL THEN
1768 NEW.centroid := place_centroid;
1778 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1784 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1786 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1787 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1788 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1789 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1791 IF OLD.rank_address < 30 THEN
1793 -- mark everything linked to this place for re-indexing
1794 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1795 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1796 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1798 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1799 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1801 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1802 b := deleteRoad(OLD.partition, OLD.place_id);
1804 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1805 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1806 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1810 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1812 IF OLD.rank_address < 26 THEN
1813 b := deleteLocationArea(OLD.partition, OLD.place_id);
1816 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1818 IF OLD.name is not null THEN
1819 b := deleteSearchName(OLD.partition, OLD.place_id);
1822 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1824 DELETE FROM place_addressline where place_id = OLD.place_id;
1826 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1828 -- remove from tables for special search
1829 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1830 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1832 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1835 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1843 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1849 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1851 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1852 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1853 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1858 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;
1866 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1871 existingplacex RECORD;
1872 existinggeometry GEOMETRY;
1873 existingplace_id BIGINT;
1878 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1879 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1881 IF FALSE and NEW.osm_type = 'R' THEN
1882 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;
1883 --DEBUG: RAISE WARNING '%', existingplacex;
1886 -- Just block these - lots and pointless
1887 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1890 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1894 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
1895 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1896 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1897 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1901 -- Patch in additional country names
1902 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1903 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1906 -- Have we already done this place?
1907 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;
1909 -- Get the existing place_id
1910 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;
1912 -- Handle a place changing type by removing the old data
1913 -- My generated 'place' types are causing havok because they overlap with real keys
1914 -- TODO: move them to their own special purpose key/class to avoid collisions
1915 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1916 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');
1919 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
1920 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
1923 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1924 AND st_area(existing.geometry) > 0.02
1925 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1926 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1928 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1929 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1933 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1934 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1936 -- 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
1937 IF existingplacex.osm_type IS NULL THEN
1939 IF existing.osm_type IS NOT NULL THEN
1940 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1943 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1944 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1945 street, isin, postcode, country_code, extratags, geometry)
1946 values (NEW.osm_type
1961 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
1966 -- Various ways to do the update
1968 -- Debug, what's changed?
1970 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1971 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1973 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1974 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1976 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1977 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1979 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1980 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1982 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1983 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1985 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1986 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1990 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1991 IF existing.geometry::text != NEW.geometry::text
1992 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1993 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1996 -- Get the version of the geometry actually used (in placex table)
1997 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;
1999 -- Performance limit
2000 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2002 -- 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
2003 update placex set indexed_status = 2 where indexed_status = 0 and
2004 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2005 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2006 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2008 update placex set indexed_status = 2 where indexed_status = 0 and
2009 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2010 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2011 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2017 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2018 IF FALSE AND existingplacex.rank_search < 26
2019 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2020 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2021 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2022 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2023 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2024 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2027 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2029 IF st_area(NEW.geometry) < 0.5 THEN
2030 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2031 and placex.place_id = place_addressline.place_id and indexed_status = 0
2032 and (rank_search < 28 or name is not null);
2039 -- Anything else has changed - reindex the lot
2040 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2041 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2042 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2043 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2044 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2045 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2047 -- performance, can't take the load of re-indexing a whole country / huge area
2048 IF st_area(NEW.geometry) < 0.5 THEN
2049 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2050 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2057 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2058 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2059 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2060 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2061 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2062 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2063 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2064 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2065 OR existing.geometry::text != NEW.geometry::text
2070 housenumber = NEW.housenumber,
2071 street = NEW.street,
2073 postcode = NEW.postcode,
2074 country_code = NEW.country_code,
2075 extratags = NEW.extratags,
2076 geometry = NEW.geometry
2077 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2081 housenumber = NEW.housenumber,
2082 street = NEW.street,
2084 postcode = NEW.postcode,
2085 country_code = NEW.country_code,
2086 parent_place_id = null,
2087 extratags = NEW.extratags,
2089 geometry = NEW.geometry
2090 where place_id = existingplacex.place_id;
2094 -- Abort the add (we modified the existing place instead)
2098 $$ LANGUAGE plpgsql;
2100 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2107 IF name is null THEN
2111 search := languagepref;
2113 FOR j IN 1..array_upper(search, 1) LOOP
2114 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2115 return trim(name->search[j]);
2122 LANGUAGE plpgsql IMMUTABLE;
2124 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2127 searchnodes INTEGER[];
2132 searchnodes := '{}';
2133 FOR j IN 1..array_upper(way_ids, 1) LOOP
2135 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2137 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2138 searchnodes := searchnodes || location.nodes;
2143 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2146 LANGUAGE plpgsql IMMUTABLE;
2148 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2159 search := ARRAY['ref'];
2162 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2165 select rank_address,name,distance,length(name::text) as namelength
2166 from place_addressline join placex on (address_place_id = placex.place_id)
2167 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2168 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2170 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2171 FOR j IN 1..array_upper(search, 1) LOOP
2172 FOR k IN 1..array_upper(location.name, 1) LOOP
2173 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
2174 result[(100 - location.rank_address)] := trim(location.name[k].value);
2175 found := location.rank_address;
2182 RETURN array_to_string(result,', ');
2187 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2199 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2200 currresult := trim(get_name_by_language(location.name, languagepref));
2201 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2202 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2203 prevresult := currresult;
2207 RETURN array_to_string(result,', ');
2212 DROP TYPE addressline CASCADE;
2213 create type addressline as (
2220 admin_level INTEGER,
2223 rank_address INTEGER,
2227 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2230 for_place_id BIGINT;
2235 countrylocation RECORD;
2236 searchcountrycode varchar(2);
2237 searchhousenumber TEXT;
2238 searchhousename HSTORE;
2239 searchrankaddress INTEGER;
2240 searchpostcode TEXT;
2247 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2248 WHERE place_id = in_place_id
2249 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2251 IF for_place_id IS NULL THEN
2252 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2253 WHERE place_id = in_place_id
2254 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2257 IF for_place_id IS NULL THEN
2258 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2259 WHERE place_id = in_place_id and rank_address = 30
2260 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2263 IF for_place_id IS NULL THEN
2264 for_place_id := in_place_id;
2265 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2266 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2269 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2272 hadcountry := false;
2274 select placex.place_id, osm_type, osm_id,
2275 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2276 class, type, admin_level, true as fromarea, true as isaddress,
2277 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2278 0 as distance, calculated_country_code
2280 where place_id = for_place_id
2282 --RAISE WARNING '%',location;
2283 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2284 searchcountrycode := location.calculated_country_code;
2286 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2287 location.isaddress := FALSE;
2289 IF location.rank_address = 4 AND location.isaddress THEN
2292 IF location.rank_address < 4 AND NOT hadcountry THEN
2293 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2294 IF countryname IS NOT NULL THEN
2295 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2296 RETURN NEXT countrylocation;
2299 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2300 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2301 location.distance)::addressline;
2302 RETURN NEXT countrylocation;
2303 found := location.rank_address;
2307 select placex.place_id, osm_type, osm_id,
2308 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2309 class, type, admin_level, fromarea, isaddress,
2310 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,
2311 distance,calculated_country_code
2312 from place_addressline join placex on (address_place_id = placex.place_id)
2313 where place_addressline.place_id = for_place_id
2314 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2315 and address_place_id != for_place_id
2316 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2317 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2319 --RAISE WARNING '%',location;
2320 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2321 searchcountrycode := location.calculated_country_code;
2323 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2324 location.isaddress := FALSE;
2326 IF location.rank_address = 4 AND location.isaddress THEN
2329 IF location.rank_address < 4 AND NOT hadcountry THEN
2330 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2331 IF countryname IS NOT NULL THEN
2332 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2333 RETURN NEXT countrylocation;
2336 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2337 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2338 location.distance)::addressline;
2339 RETURN NEXT countrylocation;
2340 found := location.rank_address;
2344 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2345 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2346 IF countryname IS NOT NULL THEN
2347 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2348 RETURN NEXT location;
2352 IF searchcountrycode IS NOT NULL THEN
2353 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2354 RETURN NEXT location;
2357 IF searchhousename IS NOT NULL THEN
2358 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2359 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2360 RETURN NEXT location;
2363 IF searchhousenumber IS NOT NULL THEN
2364 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2365 RETURN NEXT location;
2368 IF searchpostcode IS NOT NULL THEN
2369 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2370 RETURN NEXT location;
2378 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2381 result place_boundingbox;
2382 numfeatures integer;
2384 select * from place_boundingbox into result where place_id = search_place_id;
2385 IF result.place_id IS NULL THEN
2386 -- remove isaddress = true because if there is a matching polygon it always wins
2387 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2388 insert into place_boundingbox select place_id,
2389 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2390 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2391 numfeatures, ST_Area(geometry),
2392 geometry as area from location_area where place_id = search_place_id;
2393 select * from place_boundingbox into result where place_id = search_place_id;
2395 IF result.place_id IS NULL THEN
2397 insert into place_boundingbox select address_place_id,
2398 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2399 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2400 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2401 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2402 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)
2403 where address_place_id = search_place_id
2404 -- and (isaddress = true OR place_id = search_place_id)
2405 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2406 group by address_place_id limit 1;
2407 select * from place_boundingbox into result where place_id = search_place_id;
2414 -- don't do the operation if it would be slow
2415 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2418 result place_boundingbox;
2419 numfeatures integer;
2422 select * from place_boundingbox into result where place_id = search_place_id;
2423 IF result IS NULL AND rank > 14 THEN
2424 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2425 insert into place_boundingbox select place_id,
2426 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2427 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2428 numfeatures, ST_Area(geometry),
2429 geometry as area from location_area where place_id = search_place_id;
2430 select * from place_boundingbox into result where place_id = search_place_id;
2432 IF result IS NULL THEN
2433 select rank_search from placex where place_id = search_place_id into rank;
2436 insert into place_boundingbox select address_place_id,
2437 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2438 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2439 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2440 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2441 from place_addressline join placex using (place_id)
2442 where address_place_id = search_place_id
2443 and (isaddress = true OR place_id = search_place_id)
2444 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2445 group by address_place_id limit 1;
2446 select * from place_boundingbox into result where place_id = search_place_id;
2454 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2457 result place_boundingbox;
2458 numfeatures integer;
2462 housenumber = place.housenumber,
2463 street = place.street,
2465 postcode = place.postcode,
2466 country_code = place.country_code,
2467 parent_place_id = null
2469 where placex.place_id = search_place_id
2470 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2471 and place.class = placex.class and place.type = placex.type;
2472 update placex set indexed_status = 2 where place_id = search_place_id;
2473 update placex set indexed_status = 0 where place_id = search_place_id;
2479 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2485 ELSEIF rank < 4 THEN
2487 ELSEIF rank < 8 THEN
2489 ELSEIF rank < 12 THEN
2491 ELSEIF rank < 16 THEN
2493 ELSEIF rank = 16 THEN
2495 ELSEIF rank = 17 THEN
2496 RETURN 'Town / Island';
2497 ELSEIF rank = 18 THEN
2498 RETURN 'Village / Hamlet';
2499 ELSEIF rank = 20 THEN
2501 ELSEIF rank = 21 THEN
2502 RETURN 'Postcode Area';
2503 ELSEIF rank = 22 THEN
2504 RETURN 'Croft / Farm / Locality / Islet';
2505 ELSEIF rank = 23 THEN
2506 RETURN 'Postcode Area';
2507 ELSEIF rank = 25 THEN
2508 RETURN 'Postcode Point';
2509 ELSEIF rank = 26 THEN
2510 RETURN 'Street / Major Landmark';
2511 ELSEIF rank = 27 THEN
2512 RETURN 'Minory Street / Path';
2513 ELSEIF rank = 28 THEN
2514 RETURN 'House / Building';
2516 RETURN 'Other: '||rank;
2523 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2529 ELSEIF rank < 2 THEN
2531 ELSEIF rank < 4 THEN
2533 ELSEIF rank = 5 THEN
2535 ELSEIF rank < 8 THEN
2537 ELSEIF rank < 12 THEN
2539 ELSEIF rank < 16 THEN
2541 ELSEIF rank = 16 THEN
2543 ELSEIF rank = 17 THEN
2544 RETURN 'Town / Village / Hamlet';
2545 ELSEIF rank = 20 THEN
2547 ELSEIF rank = 21 THEN
2548 RETURN 'Postcode Area';
2549 ELSEIF rank = 22 THEN
2550 RETURN 'Croft / Farm / Locality / Islet';
2551 ELSEIF rank = 23 THEN
2552 RETURN 'Postcode Area';
2553 ELSEIF rank = 25 THEN
2554 RETURN 'Postcode Point';
2555 ELSEIF rank = 26 THEN
2556 RETURN 'Street / Major Landmark';
2557 ELSEIF rank = 27 THEN
2558 RETURN 'Minory Street / Path';
2559 ELSEIF rank = 28 THEN
2560 RETURN 'House / Building';
2562 RETURN 'Other: '||rank;
2569 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2576 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2577 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2584 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2592 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2594 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2595 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2597 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2605 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2606 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2611 place_centroid GEOMETRY;
2612 out_partition INTEGER;
2613 out_parent_place_id BIGINT;
2615 address_street_word_id INTEGER;
2620 place_centroid := ST_Centroid(pointgeo);
2621 out_partition := get_partition(place_centroid, in_countrycode);
2622 out_parent_place_id := null;
2624 address_street_word_id := get_name_id(make_standard_name(in_street));
2625 IF address_street_word_id IS NOT NULL THEN
2626 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2627 out_parent_place_id := location.place_id;
2631 IF out_parent_place_id IS NULL THEN
2632 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2633 out_parent_place_id := location.place_id;
2637 out_postcode := in_postcode;
2638 IF out_postcode IS NULL THEN
2639 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2641 IF out_postcode IS NULL THEN
2642 out_postcode := getNearestPostcode(out_partition, place_centroid);
2646 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2647 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2648 newpoints := newpoints + 1;
2655 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2662 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2663 IF members[i+1] = member THEN
2664 result := result || members[i];
2673 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2679 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2680 IF members[i+1] = ANY(memberLabels) THEN
2681 RETURN NEXT members[i];
2690 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2691 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2693 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2694 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
2695 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2696 ), '') AS bytea), 'UTF8');
2698 LANGUAGE SQL IMMUTABLE STRICT;
2700 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2704 RETURN decode_url_part(p);
2706 WHEN others THEN return null;
2709 LANGUAGE plpgsql IMMUTABLE;
2711 DROP TYPE wikipedia_article_match CASCADE;
2712 create type wikipedia_article_match as (
2718 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2724 wiki_article_title TEXT;
2725 wiki_article_language TEXT;
2726 result wikipedia_article_match;
2728 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'];
2730 WHILE langs[i] IS NOT NULL LOOP
2731 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2732 IF wiki_article is not null THEN
2733 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2734 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2735 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2736 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2737 wiki_article := replace(wiki_article,' ','_');
2738 wiki_article_title := trim(split_part(wiki_article, ':', 2));
2739 IF wiki_article_title IS NULL OR wiki_article_title = '' THEN
2740 wiki_article_title := trim(wiki_article);
2741 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;
2743 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2746 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2747 from wikipedia_article
2748 where language = wiki_article_language and
2749 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2751 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2752 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2753 where wikipedia_redirect.language = wiki_article_language and
2754 (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'\\',''))
2755 order by importance desc limit 1 INTO result;
2757 IF result.language is not null THEN
2768 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2769 RETURNS SETOF GEOMETRY
2783 remainingdepth INTEGER;
2788 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2790 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2791 RETURN NEXT geometry;
2795 remainingdepth := maxdepth - 1;
2796 area := ST_AREA(geometry);
2797 IF remainingdepth < 1 OR area < maxarea THEN
2798 RETURN NEXT geometry;
2802 xmin := st_xmin(geometry);
2803 xmax := st_xmax(geometry);
2804 ymin := st_ymin(geometry);
2805 ymax := st_ymax(geometry);
2806 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2808 -- if the geometry completely covers the box don't bother to slice any more
2809 IF ST_AREA(secbox) = area THEN
2810 RETURN NEXT geometry;
2814 xmid := (xmin+xmax)/2;
2815 ymid := (ymin+ymax)/2;
2818 FOR seg IN 1..4 LOOP
2821 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2824 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2827 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2830 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2833 IF st_intersects(geometry, secbox) THEN
2834 secgeo := st_intersection(geometry, secbox);
2835 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2836 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2837 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2839 RETURN NEXT geo.geom;
2851 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2852 RETURNS SETOF GEOMETRY
2857 -- 10000000000 is ~~ 1x1 degree
2858 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2859 RETURN NEXT geo.geom;