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 (
8 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
15 LANGUAGE plpgsql IMMUTABLE;
17 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
23 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
29 LANGUAGE plpgsql IMMUTABLE;
31 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
37 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
38 NEWgeometry := ST_buffer(NEWgeometry,0);
39 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
40 RETURN ST_SetSRID(ST_Point(0,0),4326);
46 LANGUAGE plpgsql IMMUTABLE;
48 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
53 -- RAISE WARNING '%',place;
54 NEWgeometry := ST_PointOnSurface(place);
55 -- 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
56 -- NEWgeometry := ST_buffer(NEWgeometry,0);
57 -- 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
61 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
64 LANGUAGE plpgsql IMMUTABLE;
66 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
67 AS '{modulepath}/nominatim.so', 'transliteration'
68 LANGUAGE c IMMUTABLE STRICT;
70 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
71 AS '{modulepath}/nominatim.so', 'gettokenstring'
72 LANGUAGE c IMMUTABLE STRICT;
74 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
79 o := gettokenstring(transliteration(name));
80 RETURN trim(substr(o,1,length(o)));
83 LANGUAGE 'plpgsql' IMMUTABLE;
85 -- returns NULL if the word is too common
86 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
91 return_word_id INTEGER;
94 lookup_token := trim(lookup_word);
95 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;
96 IF return_word_id IS NULL THEN
97 return_word_id := nextval('seq_word');
98 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
100 IF count > get_maxwordfreq() THEN
101 return_word_id := NULL;
104 RETURN return_word_id;
109 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
114 return_word_id INTEGER;
116 lookup_token := ' '||trim(lookup_word);
117 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
118 IF return_word_id IS NULL THEN
119 return_word_id := nextval('seq_word');
120 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
122 RETURN return_word_id;
127 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
132 return_word_id INTEGER;
134 lookup_token := ' '||trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
168 return_word_id INTEGER;
170 lookup_token := lookup_class||'='||lookup_type;
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := lookup_class||'='||lookup_type;
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
190 RETURN return_word_id;
195 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
200 return_word_id INTEGER;
202 lookup_token := ' '||trim(lookup_word);
203 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;
204 IF return_word_id IS NULL THEN
205 return_word_id := nextval('seq_word');
206 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
208 RETURN return_word_id;
213 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
218 nospace_lookup_token TEXT;
219 return_word_id INTEGER;
221 lookup_token := ' '||trim(lookup_word);
222 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
223 IF return_word_id IS NULL THEN
224 return_word_id := nextval('seq_word');
225 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
226 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
227 -- IF ' '||nospace_lookup_token != lookup_token THEN
228 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
231 RETURN return_word_id;
236 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
241 RETURN getorcreate_name_id(lookup_word, '');
246 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
251 return_word_id INTEGER;
253 lookup_token := trim(lookup_word);
254 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
255 RETURN return_word_id;
258 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
265 return_word_id INTEGER;
267 lookup_token := ' '||trim(lookup_word);
268 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
269 RETURN return_word_id;
272 LANGUAGE plpgsql IMMUTABLE;
274 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
279 return_word_ids INTEGER[];
281 lookup_token := ' '||trim(lookup_word);
282 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
283 RETURN return_word_ids;
286 LANGUAGE plpgsql IMMUTABLE;
288 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
295 IF array_upper(a, 1) IS NULL THEN
298 IF array_upper(b, 1) IS NULL THEN
302 FOR i IN 1..array_upper(b, 1) LOOP
303 IF NOT (ARRAY[b[i]] <@ r) THEN
310 LANGUAGE plpgsql IMMUTABLE;
312 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
321 FOR item IN SELECT (each(src)).* LOOP
323 s := make_standard_name(item.value);
324 w := getorcreate_country(s, lookup_country_code);
326 words := regexp_split_to_array(item.value, E'[,;()]');
327 IF array_upper(words, 1) != 1 THEN
328 FOR j IN 1..array_upper(words, 1) LOOP
329 s := make_standard_name(words[j]);
331 w := getorcreate_country(s, lookup_country_code);
340 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
350 result := '{}'::INTEGER[];
352 FOR item IN SELECT (each(src)).* LOOP
354 s := make_standard_name(item.value);
356 w := getorcreate_name_id(s, item.value);
358 IF not(ARRAY[w] <@ result) THEN
359 result := result || w;
362 w := getorcreate_word_id(s);
364 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
365 result := result || w;
368 words := string_to_array(s, ' ');
369 IF array_upper(words, 1) IS NOT NULL THEN
370 FOR j IN 1..array_upper(words, 1) LOOP
371 IF (words[j] != '') THEN
372 w = getorcreate_word_id(words[j]);
373 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
374 result := result || w;
380 words := regexp_split_to_array(item.value, E'[,;()]');
381 IF array_upper(words, 1) != 1 THEN
382 FOR j IN 1..array_upper(words, 1) LOOP
383 s := make_standard_name(words[j]);
385 w := getorcreate_word_id(s);
386 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
387 result := result || w;
393 s := regexp_replace(item.value, '市$', '');
394 IF s != item.value THEN
395 s := make_standard_name(s);
397 w := getorcreate_name_id(s, item.value);
398 IF NOT (ARRAY[w] <@ result) THEN
399 result := result || w;
409 LANGUAGE plpgsql IMMUTABLE;
411 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
421 result := '{}'::INTEGER[];
423 s := make_standard_name(src);
424 w := getorcreate_name_id(s, src);
426 IF NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 w := getorcreate_word_id(s);
432 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
433 result := result || w;
436 words := string_to_array(s, ' ');
437 IF array_upper(words, 1) IS NOT NULL THEN
438 FOR j IN 1..array_upper(words, 1) LOOP
439 IF (words[j] != '') THEN
440 w = getorcreate_word_id(words[j]);
441 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
448 words := regexp_split_to_array(src, E'[,;()]');
449 IF array_upper(words, 1) != 1 THEN
450 FOR j IN 1..array_upper(words, 1) LOOP
451 s := make_standard_name(words[j]);
453 w := getorcreate_word_id(s);
454 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
455 result := result || w;
461 s := regexp_replace(src, '市$', '');
463 s := make_standard_name(s);
465 w := getorcreate_name_id(s, src);
466 IF NOT (ARRAY[w] <@ result) THEN
467 result := result || w;
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 -- Try for a OSM polygon
488 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
490 RETURN nearcountry.country_code;
493 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
495 -- Try for OSM fallback data
496 -- The order is to deal with places like HongKong that are 'states' within another polygon
497 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc 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;
529 LANGUAGE plpgsql IMMUTABLE;
531 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
536 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
538 RETURN lower(nearcountry.country_default_language_code);
543 LANGUAGE plpgsql IMMUTABLE;
545 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
550 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
552 RETURN lower(nearcountry.country_default_language_codes);
557 LANGUAGE plpgsql IMMUTABLE;
559 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
564 FOR nearcountry IN select partition from country_name where country_code = in_country_code
566 RETURN nearcountry.partition;
571 LANGUAGE plpgsql IMMUTABLE;
573 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
577 DELETE FROM location_area where place_id = OLD_place_id;
578 -- TODO:location_area
584 CREATE OR REPLACE FUNCTION add_location(
586 country_code varchar(2),
590 rank_address INTEGER,
605 IF rank_search > 25 THEN
606 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
609 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
611 x := deleteLocationArea(partition, place_id, rank_search);
614 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
617 centroid := ST_Centroid(geometry);
619 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
620 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
623 ELSEIF rank_search < 26 THEN
626 IF rank_address = 0 THEN
628 ELSEIF rank_search <= 14 THEN
630 ELSEIF rank_search <= 15 THEN
632 ELSEIF rank_search <= 16 THEN
634 ELSEIF rank_search <= 17 THEN
636 ELSEIF rank_search <= 21 THEN
638 ELSEIF rank_search = 25 THEN
642 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
644 secgeo := ST_Buffer(geometry, diameter);
645 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
650 secgeo := ST_Buffer(geometry, 0.0002);
651 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
654 secgeo := ST_Buffer(geometry, 0.001);
655 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
664 CREATE OR REPLACE FUNCTION update_location(
667 place_country_code varchar(2),
670 rank_address INTEGER,
678 b := deleteLocationArea(partition, place_id, rank_search);
679 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
680 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
685 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
696 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
697 FOR childplace IN select * from search_name,place_addressline
698 where address_place_id = parent_place_id
699 and search_name.place_id = place_addressline.place_id
701 delete from search_name where place_id = childplace.place_id;
702 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
703 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
705 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
706 childplace.name_vector := childplace.name_vector || to_add;
708 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
709 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
710 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
718 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
721 newkeywords INTEGER[];
722 addedkeywords INTEGER[];
723 removedkeywords INTEGER[];
727 newkeywords := make_keywords(name);
728 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
729 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
730 where place_id = OLD_place_id into addedkeywords, removedkeywords;
732 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
734 IF #removedkeywords > 0 THEN
735 -- abort due to tokens removed
739 IF #addedkeywords > 0 THEN
740 -- short circuit - no changes
744 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
745 RETURN search_name_add_words(OLD_place_id, addedkeywords);
751 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
763 orginalstartnumber INTEGER;
764 originalnumberrange INTEGER;
769 search_place_id BIGINT;
773 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
775 ELSEIF interpolationtype = 'all' THEN
777 ELSEIF interpolationtype ~ '^\d+$' THEN
778 stepsize := interpolationtype::INTEGER;
783 select nodes from planet_osm_ways where id = wayid INTO waynodes;
785 IF array_upper(waynodes, 1) IS NULL THEN
789 select postcode, geometry from placex where osm_type = 'W' and osm_id = wayid
790 INTO defpostalcode, linegeo;
792 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
799 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
801 -- If there is a place of a type other than place/house, use that because
802 -- it is guaranteed to be the original node. For place/house types use the
803 -- one with the smallest id because the original node was created first.
804 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
805 select place_id from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and indexed_status < 100 order by (type = 'house'),place_id limit 1 INTO search_place_id;
806 IF search_place_id IS NOT NULL THEN
807 select * from placex where place_id = search_place_id INTO nextnode;
809 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
810 -- Make sure that the point is actually on the line. That might
811 -- be a bit paranoid but ensures that the algorithm still works
812 -- should osm2pgsql attempt to repair geometries.
813 splitline := split_line_on_node(linegeo, nextnode.geometry);
814 sectiongeo := ST_GeometryN(splitline, 1);
815 linegeo := ST_GeometryN(splitline, 2);
817 sectiongeo = linegeo;
819 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
821 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
822 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
823 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
825 IF (startnumber > endnumber) THEN
826 housenum := endnumber;
827 endnumber := startnumber;
828 startnumber := housenum;
829 sectiongeo := ST_Reverse(sectiongeo);
831 orginalstartnumber := startnumber;
832 originalnumberrange := endnumber - startnumber;
834 startnumber := startnumber + stepsize;
835 -- correct for odd/even
836 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
837 startnumber := startnumber - 1;
839 endnumber := endnumber - 1;
841 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
842 FOR housenum IN startnumber..endnumber BY stepsize LOOP
843 -- this should really copy postcodes but it puts a huge burden on
844 -- the system for no big benefit ideally postcodes should move up to the way
845 insert into placex (osm_type, osm_id, class, type, admin_level,
846 housenumber, street, addr_place, isin, postcode,
847 country_code, parent_place_id, rank_address, rank_search,
848 indexed_status, geometry)
849 values ('N', prevnode.osm_id, 'place', 'house', prevnode.admin_level,
850 housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
851 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search,
852 1, ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
853 newpoints := newpoints + 1;
854 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
858 -- early break if we are out of line string,
859 -- might happen when a line string loops back on itself
860 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
864 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
865 prevnode := nextnode;
869 --RAISE WARNING 'interpolation points % ',newpoints;
876 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
882 country_code VARCHAR(2);
883 default_language VARCHAR(10);
887 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
890 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
891 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
895 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
896 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
897 RAISE WARNING 'invalid geometry %',NEW.osm_id;
901 IF NEW.osm_type = 'R' THEN
902 -- invalid multipolygons can crash postgis, don't even bother to try!
905 NEW.geometry := ST_buffer(NEW.geometry,0);
906 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
907 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
912 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
914 NEW.place_id := nextval('seq_place');
915 NEW.indexed_status := 1; --STATUS_NEW
917 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
919 NEW.partition := get_partition(NEW.calculated_country_code);
920 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
922 -- copy 'name' to or from the default language (if there is a default language)
923 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
924 default_language := get_country_language_code(NEW.calculated_country_code);
925 IF default_language IS NOT NULL THEN
926 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
927 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
928 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
929 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
934 IF NEW.admin_level > 15 THEN
935 NEW.admin_level := 15;
938 IF NEW.housenumber IS NOT NULL THEN
939 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
942 IF NEW.osm_type = 'X' THEN
943 -- E'X'ternal records should already be in the right format so do nothing
945 NEW.rank_search := 30;
946 NEW.rank_address := NEW.rank_search;
948 -- By doing in postgres we have the country available to us - currently only used for postcode
949 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
951 IF NEW.postcode IS NULL THEN
952 -- most likely just a part of a multipolygon postcode boundary, throw it away
956 NEW.name := hstore('ref', NEW.postcode);
958 IF NEW.calculated_country_code = 'gb' THEN
960 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
961 NEW.rank_search := 25;
962 NEW.rank_address := 5;
963 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
964 NEW.rank_search := 23;
965 NEW.rank_address := 5;
966 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
967 NEW.rank_search := 21;
968 NEW.rank_address := 5;
971 ELSEIF NEW.calculated_country_code = 'sg' THEN
973 IF NEW.postcode ~ '^([0-9]{6})$' THEN
974 NEW.rank_search := 25;
975 NEW.rank_address := 11;
978 ELSEIF NEW.calculated_country_code = 'de' THEN
980 IF NEW.postcode ~ '^([0-9]{5})$' THEN
981 NEW.rank_search := 21;
982 NEW.rank_address := 11;
986 -- Guess at the postcode format and coverage (!)
987 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
988 NEW.rank_search := 21;
989 NEW.rank_address := 11;
991 -- Does it look splitable into and area and local code?
992 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
994 IF postcode IS NOT NULL THEN
995 NEW.rank_search := 25;
996 NEW.rank_address := 11;
997 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
998 NEW.rank_search := 21;
999 NEW.rank_address := 11;
1004 ELSEIF NEW.class = 'place' THEN
1005 IF NEW.type in ('continent') THEN
1006 NEW.rank_search := 2;
1007 NEW.rank_address := NEW.rank_search;
1008 NEW.calculated_country_code := NULL;
1009 ELSEIF NEW.type in ('sea') THEN
1010 NEW.rank_search := 2;
1011 NEW.rank_address := 0;
1012 NEW.calculated_country_code := NULL;
1013 ELSEIF NEW.type in ('country') THEN
1014 NEW.rank_search := 4;
1015 NEW.rank_address := NEW.rank_search;
1016 ELSEIF NEW.type in ('state') THEN
1017 NEW.rank_search := 8;
1018 NEW.rank_address := NEW.rank_search;
1019 ELSEIF NEW.type in ('region') THEN
1020 NEW.rank_search := 18; -- dropped from previous value of 10
1021 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1022 ELSEIF NEW.type in ('county') THEN
1023 NEW.rank_search := 12;
1024 NEW.rank_address := NEW.rank_search;
1025 ELSEIF NEW.type in ('city') THEN
1026 NEW.rank_search := 16;
1027 NEW.rank_address := NEW.rank_search;
1028 ELSEIF NEW.type in ('island') THEN
1029 NEW.rank_search := 17;
1030 NEW.rank_address := 0;
1031 ELSEIF NEW.type in ('town') THEN
1032 NEW.rank_search := 18;
1033 NEW.rank_address := 16;
1034 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1035 NEW.rank_search := 19;
1036 NEW.rank_address := 16;
1037 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1038 NEW.rank_search := 20;
1039 NEW.rank_address := NEW.rank_search;
1040 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1041 NEW.rank_search := 20;
1042 NEW.rank_address := 0;
1043 -- Irish townlands, tagged as place=locality and locality=townland
1044 IF (NEW.extratags -> 'locality') = 'townland' THEN
1045 NEW.rank_address := 20;
1047 ELSEIF NEW.type in ('neighbourhood') THEN
1048 NEW.rank_search := 22;
1049 NEW.rank_address := 22;
1050 ELSEIF NEW.type in ('house','building') THEN
1051 NEW.rank_search := 30;
1052 NEW.rank_address := NEW.rank_search;
1053 ELSEIF NEW.type in ('houses') THEN
1054 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1055 -- insert new point into place for each derived building
1056 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1057 NEW.rank_search := 28;
1058 NEW.rank_address := 0;
1061 ELSEIF NEW.class = 'boundary' THEN
1062 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1063 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1066 NEW.rank_search := NEW.admin_level * 2;
1067 IF NEW.type = 'administrative' THEN
1068 NEW.rank_address := NEW.rank_search;
1070 NEW.rank_address := 0;
1072 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1073 NEW.rank_search := 22;
1074 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1075 NEW.rank_address := NEW.rank_search;
1077 NEW.rank_address := 0;
1079 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1080 NEW.rank_search := 18;
1081 NEW.rank_address := 0;
1082 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1083 NEW.rank_search := 4;
1084 NEW.rank_address := NEW.rank_search;
1085 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1087 -- any feature more than 5 square miles is probably worth indexing
1088 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1089 NEW.rank_search := 22;
1090 NEW.rank_address := 0;
1091 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1092 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1093 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1095 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1097 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1099 ELSEIF NEW.class = 'waterway' THEN
1100 IF NEW.osm_type = 'R' THEN
1101 NEW.rank_search := 16;
1103 NEW.rank_search := 17;
1105 NEW.rank_address := 0;
1106 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
1107 NEW.rank_search := 27;
1108 NEW.rank_address := NEW.rank_search;
1109 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1110 NEW.rank_search := 26;
1111 NEW.rank_address := NEW.rank_search;
1112 ELSEIF NEW.class = 'mountain_pass' THEN
1113 NEW.rank_search := 20;
1114 NEW.rank_address := 0;
1119 IF NEW.rank_search > 30 THEN
1120 NEW.rank_search := 30;
1123 IF NEW.rank_address > 30 THEN
1124 NEW.rank_address := 30;
1127 IF (NEW.extratags -> 'capital') = 'yes' THEN
1128 NEW.rank_search := NEW.rank_search - 1;
1131 -- a country code make no sense below rank 4 (country)
1132 IF NEW.rank_search < 4 THEN
1133 NEW.calculated_country_code := NULL;
1136 -- Block import below rank 22
1137 -- IF NEW.rank_search > 22 THEN
1141 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1143 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1145 IF NEW.rank_address > 0 THEN
1146 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1147 -- Performance: We just can't handle re-indexing for country level changes
1148 IF st_area(NEW.geometry) < 1 THEN
1149 -- mark items within the geometry for re-indexing
1150 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1152 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1153 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1154 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 or (NEW.rank_search >= 16 and addr_place is not null));
1155 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1156 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 or (NEW.rank_search >= 16 and addr_place is not null));
1159 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1161 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1162 IF NEW.type='postcode' THEN
1164 ELSEIF NEW.rank_search < 16 THEN
1166 ELSEIF NEW.rank_search < 18 THEN
1168 ELSEIF NEW.rank_search < 20 THEN
1170 ELSEIF NEW.rank_search = 21 THEN
1172 ELSEIF NEW.rank_search < 24 THEN
1174 ELSEIF NEW.rank_search < 26 THEN
1175 diameter := 0.002; -- 100 to 200 meters
1176 ELSEIF NEW.rank_search < 28 THEN
1177 diameter := 0.001; -- 50 to 100 meters
1179 IF diameter > 0 THEN
1180 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1181 IF NEW.rank_search >= 26 THEN
1182 -- roads may cause reparenting for >27 rank places
1183 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1184 ELSEIF NEW.rank_search >= 16 THEN
1185 -- up to rank 16, street-less addresses may need reparenting
1186 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 or addr_place is not null);
1188 -- for all other places the search terms may change as well
1189 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);
1195 -- add to tables for special search
1196 -- Note: won't work on initial import because the classtype tables
1197 -- do not yet exist. It won't hurt either.
1198 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1199 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1201 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1202 USING NEW.place_id, ST_Centroid(NEW.geometry);
1206 -- IF NEW.rank_search < 26 THEN
1207 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1216 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1221 place_centroid GEOMETRY;
1223 search_maxdistance FLOAT[];
1224 search_mindistance FLOAT[];
1225 address_havelevel BOOLEAN[];
1232 relation_members TEXT[];
1234 linkedplacex RECORD;
1235 search_diameter FLOAT;
1236 search_prevdiameter FLOAT;
1237 search_maxrank INTEGER;
1238 address_maxrank INTEGER;
1239 address_street_word_id INTEGER;
1240 address_street_word_ids INTEGER[];
1241 parent_place_id_rank BIGINT;
1246 location_rank_search INTEGER;
1247 location_distance FLOAT;
1248 location_parent GEOMETRY;
1249 location_isaddress BOOLEAN;
1250 location_keywords INTEGER[];
1254 default_language TEXT;
1255 name_vector INTEGER[];
1256 nameaddress_vector INTEGER[];
1258 linked_node_id BIGINT;
1264 IF OLD.indexed_status = 100 THEN
1265 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1266 delete from placex where place_id = OLD.place_id;
1270 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1274 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1276 --RAISE WARNING '%',NEW.place_id;
1277 --RAISE WARNING '%', NEW;
1279 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1280 -- Silently do nothing
1284 -- TODO: this test is now redundant?
1285 IF OLD.indexed_status != 0 THEN
1287 NEW.indexed_date = now();
1289 result := deleteSearchName(NEW.partition, NEW.place_id);
1290 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1291 result := deleteRoad(NEW.partition, NEW.place_id);
1292 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1293 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1295 IF NEW.linked_place_id is not null THEN
1299 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1300 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1304 -- Speed up searches - just use the centroid of the feature
1305 -- cheaper but less acurate
1306 place_centroid := ST_PointOnSurface(NEW.geometry);
1307 NEW.centroid := null;
1309 -- recalculate country and partition
1310 IF NEW.rank_search = 4 THEN
1311 -- for countries, believe the mapped country code,
1312 -- so that we remain in the right partition if the boundaries
1314 NEW.partition := get_partition(lower(NEW.country_code));
1315 IF NEW.partition = 0 THEN
1316 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1317 NEW.partition := get_partition(NEW.calculated_country_code);
1319 NEW.calculated_country_code := lower(NEW.country_code);
1322 IF NEW.rank_search > 4 THEN
1323 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1324 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1326 NEW.calculated_country_code := NULL;
1328 NEW.partition := get_partition(NEW.calculated_country_code);
1330 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1332 -- waterway ways are linked when they are part of a relation and have the same class/type
1333 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1334 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1336 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1337 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1338 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1339 FOR linked_node_id IN SELECT place_id FROM placex
1340 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1341 and class = NEW.class and type = NEW.type
1342 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1344 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1351 -- Adding ourselves to the list simplifies address calculations later
1352 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1354 -- What level are we searching from
1355 search_maxrank := NEW.rank_search;
1357 -- Thought this wasn't needed but when we add new languages to the country_name table
1358 -- we need to update the existing names
1359 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1360 default_language := get_country_language_code(NEW.calculated_country_code);
1361 IF default_language IS NOT NULL THEN
1362 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1363 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1364 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1365 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1370 -- Initialise the name vector using our name
1371 name_vector := make_keywords(NEW.name);
1372 nameaddress_vector := '{}'::int[];
1374 -- some tag combinations add a special id for search
1375 tagpairid := get_tagpair(NEW.class,NEW.type);
1376 IF tagpairid IS NOT NULL THEN
1377 name_vector := name_vector + tagpairid;
1381 address_havelevel[i] := false;
1384 NEW.importance := null;
1385 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1386 IF NEW.importance IS NULL THEN
1387 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;
1390 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1392 -- For low level elements we inherit from our parent road
1393 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1395 --RAISE WARNING 'finding street for %', NEW;
1397 -- We won't get a better centroid, besides these places are too small to care
1398 NEW.centroid := place_centroid;
1400 NEW.parent_place_id := null;
1402 -- to do that we have to find our parent road
1403 -- Copy data from linked items (points on ways, addr:street links, relations)
1404 -- Note that addr:street links can only be indexed once the street itself is indexed
1405 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1407 -- if there is no address information, see if we can get it from a surrounding building
1408 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1409 FOR location IN select * from placex where ST_Covers(geometry, place_centroid) and rank_search > 28 and (housenumber is not null or street is not null or addr_place is not null) AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1411 NEW.housenumber := location.housenumber;
1412 NEW.street := location.street;
1413 NEW.addr_place := location.addr_place;
1417 -- Is this node part of a relation?
1418 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1420 -- At the moment we only process one type of relation - associatedStreet
1421 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1422 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1423 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1424 --RAISE WARNING 'node in relation %',relation;
1425 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1426 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1432 --RAISE WARNING 'x1';
1433 -- Is this node part of a way?
1434 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1435 --RAISE WARNING '%', way;
1436 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1438 --RAISE WARNING '%', location;
1439 -- Way IS a road then we are on it - that must be our road
1440 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1441 --RAISE WARNING 'node in way that is a street %',location;
1442 NEW.parent_place_id := location.place_id;
1445 -- Is the WAY part of a relation
1446 IF NEW.parent_place_id IS NULL THEN
1447 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1449 -- At the moment we only process one type of relation - associatedStreet
1450 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1451 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1452 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1453 --RAISE WARNING 'node in way that is in a relation %',relation;
1454 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1455 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1462 -- If the way contains an explicit name of a street copy it
1463 -- Slightly less strict then above because data is copied from any object.
1464 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1465 --RAISE WARNING 'node in way that has a streetname %',location;
1466 NEW.street := location.street;
1467 NEW.addr_place := location.addr_place;
1470 -- If this way is a street interpolation line then it is probably as good as we are going to get
1471 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND NEW.addr_place IS NULL AND location.class = 'place' and location.type='houses' THEN
1472 -- Try and find a way that is close roughly parellel to this line
1473 FOR relation IN SELECT place_id FROM placex
1474 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1475 and st_geometrytype(location.geometry) in ('ST_LineString')
1476 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1477 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1478 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1480 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1481 NEW.parent_place_id := relation.place_id;
1490 --RAISE WARNING 'x2';
1492 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1493 -- Is this way part of a relation?
1494 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1496 -- At the moment we only process one type of relation - associatedStreet
1497 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1498 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1499 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1500 --RAISE WARNING 'way that is in a relation %',relation;
1501 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1502 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1509 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1511 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1512 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1513 IF address_street_word_ids IS NOT NULL THEN
1514 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1515 NEW.parent_place_id := location.place_id;
1520 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1521 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1522 IF address_street_word_ids IS NOT NULL THEN
1523 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1524 NEW.parent_place_id := location.place_id;
1529 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1530 -- Still nothing, just use the nearest road
1531 IF NEW.parent_place_id IS NULL THEN
1532 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1533 NEW.parent_place_id := location.place_id;
1538 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1540 -- If we didn't find any road fallback to standard method
1541 IF NEW.parent_place_id IS NOT NULL THEN
1543 -- Add the street to the address as zero distance to force to front of list
1544 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1545 address_havelevel[26] := true;
1547 -- Import address details from parent, reclculating distance in process
1548 -- 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
1549 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1550 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1552 -- Get the details of the parent road
1553 select * from search_name where place_id = NEW.parent_place_id INTO location;
1554 NEW.calculated_country_code := location.country_code;
1556 --RAISE WARNING '%', NEW.name;
1557 -- If there is no name it isn't searchable, don't bother to create a search record
1558 IF NEW.name is NULL THEN
1562 -- Merge address from parent
1563 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1564 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1566 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1567 -- Just be happy with inheriting from parent road only
1569 IF NEW.rank_search <= 25 THEN
1570 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1573 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, NEW.geometry);
1580 -- RAISE WARNING ' INDEXING Started:';
1581 -- RAISE WARNING ' INDEXING: %',NEW;
1583 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1585 -- see if we have any special relation members
1586 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1588 -- RAISE WARNING 'get_osm_rel_members, label';
1589 IF relation_members IS NOT NULL THEN
1590 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1592 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1593 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1595 -- If we don't already have one use this as the centre point of the geometry
1596 IF NEW.centroid IS NULL THEN
1597 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1600 -- merge in the label name, re-init word vector
1601 IF NOT linkedPlacex.name IS NULL THEN
1602 NEW.name := linkedPlacex.name || NEW.name;
1603 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1606 -- merge in extra tags
1607 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1609 -- mark the linked place (excludes from search results)
1610 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1612 -- keep a note of the node id in case we need it for wikipedia in a bit
1613 linked_node_id := linkedPlacex.osm_id;
1618 IF NEW.centroid IS NULL THEN
1620 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1622 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1623 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1625 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1626 -- But that can be fixed by explicitly setting the label in the data
1627 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1628 AND NEW.rank_address = linkedPlacex.rank_address THEN
1630 -- If we don't already have one use this as the centre point of the geometry
1631 IF NEW.centroid IS NULL THEN
1632 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1635 -- merge in the name, re-init word vector
1636 IF NOT linkedPlacex.name IS NULL THEN
1637 NEW.name := linkedPlacex.name || NEW.name;
1638 name_vector := make_keywords(NEW.name);
1641 -- merge in extra tags
1642 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1644 -- mark the linked place (excludes from search results)
1645 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1647 -- keep a note of the node id in case we need it for wikipedia in a bit
1648 linked_node_id := linkedPlacex.osm_id;
1660 -- Name searches can be done for ways as well as relations
1661 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1663 -- not found one yet? how about doing a name search
1664 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1666 FOR linkedPlacex IN select placex.* from placex WHERE
1667 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1668 AND placex.rank_address = NEW.rank_address
1669 AND placex.place_id != NEW.place_id
1670 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1671 AND st_covers(NEW.geometry, placex.geometry)
1674 -- If we don't already have one use this as the centre point of the geometry
1675 IF NEW.centroid IS NULL THEN
1676 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1679 -- merge in the name, re-init word vector
1680 NEW.name := linkedPlacex.name || NEW.name;
1681 name_vector := make_keywords(NEW.name);
1683 -- merge in extra tags
1684 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1686 -- mark the linked place (excludes from search results)
1687 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1689 -- keep a note of the node id in case we need it for wikipedia in a bit
1690 linked_node_id := linkedPlacex.osm_id;
1694 IF NEW.centroid IS NOT NULL THEN
1695 place_centroid := NEW.centroid;
1696 -- Place might have had only a name tag before but has now received translations
1697 -- from the linked place. Make sure a name tag for the default language exists in
1699 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1700 default_language := get_country_language_code(NEW.calculated_country_code);
1701 IF default_language IS NOT NULL THEN
1702 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1703 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1704 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1705 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1711 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1712 IF NEW.importance is null THEN
1713 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1715 -- Still null? how about looking it up by the node id
1716 IF NEW.importance IS NULL THEN
1717 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;
1722 -- make sure all names are in the word table
1723 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1724 perform create_country(NEW.name, lower(NEW.country_code));
1727 NEW.parent_place_id = 0;
1728 parent_place_id_rank = 0;
1730 -- convert isin to array of tokenids
1731 isin_tokens := '{}'::int[];
1732 IF NEW.isin IS NOT NULL THEN
1733 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1734 IF array_upper(isin, 1) IS NOT NULL THEN
1735 FOR i IN 1..array_upper(isin, 1) LOOP
1736 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1737 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1738 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1739 isin_tokens := isin_tokens || address_street_word_id;
1742 -- merge word into address vector
1743 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1744 IF address_street_word_id IS NOT NULL THEN
1745 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1750 IF NEW.postcode IS NOT NULL THEN
1751 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1752 IF array_upper(isin, 1) IS NOT NULL THEN
1753 FOR i IN 1..array_upper(isin, 1) LOOP
1754 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1755 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1756 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1757 isin_tokens := isin_tokens || address_street_word_id;
1760 -- merge into address vector
1761 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1762 IF address_street_word_id IS NOT NULL THEN
1763 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1769 -- for the USA we have an additional address table. Merge in zip codes from there too
1770 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1771 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1772 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1773 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1774 isin_tokens := isin_tokens || address_street_word_id;
1776 -- also merge in the single word version
1777 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1778 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1782 -- RAISE WARNING 'ISIN: %', isin_tokens;
1784 -- Process area matches
1785 location_rank_search := 0;
1786 location_distance := 0;
1787 location_parent := NULL;
1788 -- added ourself as address already
1789 address_havelevel[NEW.rank_address] := true;
1790 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1791 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1793 --RAISE WARNING ' AREA: %',location;
1795 IF location.rank_address != location_rank_search THEN
1796 location_rank_search := location.rank_address;
1797 IF location.isguess THEN
1798 location_distance := location.distance * 1.5;
1800 IF location.rank_address <= 12 THEN
1801 -- for county and above, if we have an area consider that exact
1802 -- (It would be nice to relax the constraint for places close to
1803 -- the boundary but we'd need the exact geometry for that. Too
1805 location_distance = 0;
1807 -- Below county level remain slightly fuzzy.
1808 location_distance := location.distance * 0.5;
1812 CONTINUE WHEN location.keywords <@ location_keywords;
1815 IF location.distance < location_distance OR NOT location.isguess THEN
1816 location_keywords := location.keywords;
1818 location_isaddress := NOT address_havelevel[location.rank_address];
1819 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1820 location_isaddress := ST_Contains(location_parent,location.centroid);
1823 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1824 -- Add it to the list of search terms
1825 IF location.rank_search > 4 THEN
1826 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1828 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1830 IF location_isaddress THEN
1832 address_havelevel[location.rank_address] := true;
1833 IF NOT location.isguess THEN
1834 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1837 IF location.rank_address > parent_place_id_rank THEN
1838 NEW.parent_place_id = location.place_id;
1839 parent_place_id_rank = location.rank_address;
1844 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1850 -- try using the isin value to find parent places
1851 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1852 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1853 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1854 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1856 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1858 --RAISE WARNING ' ISIN: %',location;
1860 IF location.rank_search > 4 THEN
1861 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1862 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1863 address_havelevel[location.rank_address] := true;
1865 IF location.rank_address > parent_place_id_rank THEN
1866 NEW.parent_place_id = location.place_id;
1867 parent_place_id_rank = location.rank_address;
1877 -- for long ways we should add search terms for the entire length
1878 IF st_length(NEW.geometry) > 0.05 THEN
1880 location_rank_search := 0;
1881 location_distance := 0;
1883 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1885 IF location.rank_address != location_rank_search THEN
1886 location_rank_search := location.rank_address;
1887 location_distance := location.distance * 1.5;
1890 IF location.rank_search > 4 AND location.distance < location_distance THEN
1892 -- Add it to the list of search terms
1893 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1894 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1902 -- if we have a name add this to the name search table
1903 IF NEW.name IS NOT NULL THEN
1905 IF NEW.rank_search <= 25 THEN
1906 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1909 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1910 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1913 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, NEW.geometry);
1917 -- If we've not managed to pick up a better one - default centroid
1918 IF NEW.centroid IS NULL THEN
1919 NEW.centroid := place_centroid;
1929 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1935 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1937 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1938 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1939 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1940 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1942 IF OLD.rank_address < 30 THEN
1944 -- mark everything linked to this place for re-indexing
1945 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1946 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1947 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1949 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1950 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1952 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1953 b := deleteRoad(OLD.partition, OLD.place_id);
1955 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1956 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1957 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1961 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1963 IF OLD.rank_address < 26 THEN
1964 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1967 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1969 IF OLD.name is not null THEN
1970 b := deleteSearchName(OLD.partition, OLD.place_id);
1973 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1975 DELETE FROM place_addressline where place_id = OLD.place_id;
1977 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1979 -- remove from tables for special search
1980 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1981 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1983 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1986 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1994 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2000 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2002 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2003 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2004 SELECT bool_or(not (rank_address = 0 or rank_address > 26)) as ranked FROM placex WHERE osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type INTO has_rank;
2006 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2012 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;
2020 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2025 existingplacex RECORD;
2026 existinggeometry GEOMETRY;
2027 existingplace_id BIGINT;
2032 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2033 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2035 IF FALSE and NEW.osm_type = 'R' THEN
2036 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;
2037 --DEBUG: RAISE WARNING '%', existingplacex;
2040 -- Just block these - lots and pointless
2041 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2042 -- if the name tag was removed, older versions might still be lurking in the place table
2043 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2047 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
2048 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2049 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2050 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2054 -- Patch in additional country names
2055 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2056 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2059 -- Have we already done this place?
2060 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;
2062 -- Get the existing place_id
2063 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;
2065 -- Handle a place changing type by removing the old data
2066 -- My generated 'place' types are causing havok because they overlap with real keys
2067 -- TODO: move them to their own special purpose key/class to avoid collisions
2068 IF existing.osm_type IS NULL THEN
2069 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2072 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2073 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2076 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2077 AND st_area(existing.geometry) > 0.02
2078 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2079 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2081 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2082 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2086 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2087 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2089 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2090 IF existingplacex.osm_type IS NULL OR
2091 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2094 IF existingplacex.osm_type IS NOT NULL THEN
2095 -- sanity check: ignore admin_level changes on places with too many active children
2096 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2097 --LIMIT INDEXING: SELECT count(*) FROM (SELECT 'a' FROM placex , place_addressline where address_place_id = existingplacex.place_id and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress LIMIT 100001) sub INTO i;
2098 --LIMIT INDEXING: IF i > 100000 THEN
2099 --LIMIT INDEXING: RETURN null;
2100 --LIMIT INDEXING: END IF;
2103 IF existing.osm_type IS NOT NULL THEN
2104 -- pathological case caused by the triggerless copy into place during initial import
2105 -- force delete even for large areas, it will be reinserted later
2106 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2107 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2110 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2111 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2112 street, addr_place, isin, postcode, country_code, extratags, geometry)
2113 values (NEW.osm_type
2129 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2134 -- Various ways to do the update
2136 -- Debug, what's changed?
2138 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2139 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2141 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2142 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2144 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2145 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2147 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2148 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2150 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2151 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2153 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2154 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2156 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2157 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2161 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2162 IF existing.geometry::text != NEW.geometry::text
2163 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2164 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2167 -- Get the version of the geometry actually used (in placex table)
2168 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;
2170 -- Performance limit
2171 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2173 -- 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
2174 update placex set indexed_status = 2 where indexed_status = 0 and
2175 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2176 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2177 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2179 update placex set indexed_status = 2 where indexed_status = 0 and
2180 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2181 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2182 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2188 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2189 IF FALSE AND existingplacex.rank_search < 26
2190 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2191 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2192 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2193 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2194 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2195 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2196 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2199 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2201 IF st_area(NEW.geometry) < 0.5 THEN
2202 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2203 and placex.place_id = place_addressline.place_id and indexed_status = 0
2204 and (rank_search < 28 or name is not null);
2211 -- Anything else has changed - reindex the lot
2212 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2213 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2214 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2215 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2216 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2217 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2218 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2220 -- performance, can't take the load of re-indexing a whole country / huge area
2221 IF st_area(NEW.geometry) < 0.5 THEN
2222 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2223 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2230 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2231 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2232 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2233 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2234 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2235 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2236 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2237 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2238 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2239 OR existing.geometry::text != NEW.geometry::text
2244 housenumber = NEW.housenumber,
2245 street = NEW.street,
2246 addr_place = NEW.addr_place,
2248 postcode = NEW.postcode,
2249 country_code = NEW.country_code,
2250 extratags = NEW.extratags,
2251 admin_level = NEW.admin_level,
2252 geometry = NEW.geometry
2253 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2255 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2256 IF NEW.postcode IS NULL THEN
2257 -- postcode was deleted, no longer retain in placex
2258 DELETE FROM placex where place_id = existingplacex.place_id;
2262 NEW.name := hstore('ref', NEW.postcode);
2267 housenumber = NEW.housenumber,
2268 street = NEW.street,
2269 addr_place = NEW.addr_place,
2271 postcode = NEW.postcode,
2272 country_code = NEW.country_code,
2273 parent_place_id = null,
2274 extratags = NEW.extratags,
2275 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2277 geometry = NEW.geometry
2278 where place_id = existingplacex.place_id;
2282 -- Abort the add (we modified the existing place instead)
2286 $$ LANGUAGE plpgsql;
2288 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2295 IF name is null THEN
2299 search := languagepref;
2301 FOR j IN 1..array_upper(search, 1) LOOP
2302 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2303 return trim(name->search[j]);
2307 -- anything will do as a fallback - just take the first name type thing there is
2308 search := avals(name);
2312 LANGUAGE plpgsql IMMUTABLE;
2315 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2326 search := ARRAY['ref'];
2329 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2332 select rank_address,name,distance,length(name::text) as namelength
2333 from place_addressline join placex on (address_place_id = placex.place_id)
2334 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2335 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2337 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2338 FOR j IN 1..array_upper(search, 1) LOOP
2339 FOR k IN 1..array_upper(location.name, 1) LOOP
2340 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
2341 result[(100 - location.rank_address)] := trim(location.name[k].value);
2342 found := location.rank_address;
2349 RETURN array_to_string(result,', ');
2354 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2366 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2367 currresult := trim(get_name_by_language(location.name, languagepref));
2368 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2369 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2370 prevresult := currresult;
2374 RETURN array_to_string(result,', ');
2379 DROP TYPE IF EXISTS addressline CASCADE;
2380 create type addressline as (
2387 admin_level INTEGER,
2390 rank_address INTEGER,
2394 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2397 for_place_id BIGINT;
2402 countrylocation RECORD;
2403 searchcountrycode varchar(2);
2404 searchhousenumber TEXT;
2405 searchhousename HSTORE;
2406 searchrankaddress INTEGER;
2407 searchpostcode TEXT;
2414 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2415 WHERE place_id = in_place_id
2416 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2418 IF for_place_id IS NULL THEN
2419 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2420 WHERE place_id = in_place_id
2421 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2424 IF for_place_id IS NULL THEN
2425 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2426 WHERE place_id = in_place_id and rank_address = 30
2427 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2430 IF for_place_id IS NULL THEN
2431 for_place_id := in_place_id;
2432 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2433 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2436 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2439 hadcountry := false;
2441 select placex.place_id, osm_type, osm_id,
2442 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2443 class, type, admin_level, true as fromarea, true as isaddress,
2444 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2445 0 as distance, calculated_country_code, postcode
2447 where place_id = for_place_id
2449 --RAISE WARNING '%',location;
2450 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2451 searchcountrycode := location.calculated_country_code;
2453 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2454 location.isaddress := FALSE;
2456 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2457 searchpostcode := location.postcode;
2459 IF location.rank_address = 4 AND location.isaddress THEN
2462 IF location.rank_address < 4 AND NOT hadcountry THEN
2463 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2464 IF countryname IS NOT NULL THEN
2465 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2466 RETURN NEXT countrylocation;
2469 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2470 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2471 location.distance)::addressline;
2472 RETURN NEXT countrylocation;
2473 found := location.rank_address;
2477 select placex.place_id, osm_type, osm_id,
2478 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2479 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2480 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2481 admin_level, fromarea, isaddress,
2482 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,
2483 distance,calculated_country_code,postcode
2484 from place_addressline join placex on (address_place_id = placex.place_id)
2485 where place_addressline.place_id = for_place_id
2486 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2487 and address_place_id != for_place_id
2488 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2489 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2491 --RAISE WARNING '%',location;
2492 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2493 searchcountrycode := location.calculated_country_code;
2495 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2496 location.isaddress := FALSE;
2498 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2499 searchpostcode := location.postcode;
2501 IF location.rank_address = 4 AND location.isaddress THEN
2504 IF location.rank_address < 4 AND NOT hadcountry THEN
2505 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2506 IF countryname IS NOT NULL THEN
2507 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2508 RETURN NEXT countrylocation;
2511 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2512 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2513 location.distance)::addressline;
2514 RETURN NEXT countrylocation;
2515 found := location.rank_address;
2519 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2520 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2521 IF countryname IS NOT NULL THEN
2522 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2523 RETURN NEXT location;
2527 IF searchcountrycode IS NOT NULL THEN
2528 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2529 RETURN NEXT location;
2532 IF searchhousename IS NOT NULL THEN
2533 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2534 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2535 RETURN NEXT location;
2538 IF searchhousenumber IS NOT NULL THEN
2539 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2540 RETURN NEXT location;
2543 IF searchpostcode IS NOT NULL THEN
2544 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2545 RETURN NEXT location;
2554 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2557 numfeatures integer;
2561 housenumber = place.housenumber,
2562 street = place.street,
2563 addr_place = place.addr_place,
2565 postcode = place.postcode,
2566 country_code = place.country_code,
2567 parent_place_id = null
2569 where placex.place_id = search_place_id
2570 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2571 and place.class = placex.class and place.type = placex.type;
2572 update placex set indexed_status = 2 where place_id = search_place_id;
2573 update placex set indexed_status = 0 where place_id = search_place_id;
2579 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2585 ELSEIF rank < 4 THEN
2587 ELSEIF rank < 8 THEN
2589 ELSEIF rank < 12 THEN
2591 ELSEIF rank < 16 THEN
2593 ELSEIF rank = 16 THEN
2595 ELSEIF rank = 17 THEN
2596 RETURN 'Town / Island';
2597 ELSEIF rank = 18 THEN
2598 RETURN 'Village / Hamlet';
2599 ELSEIF rank = 20 THEN
2601 ELSEIF rank = 21 THEN
2602 RETURN 'Postcode Area';
2603 ELSEIF rank = 22 THEN
2604 RETURN 'Croft / Farm / Locality / Islet';
2605 ELSEIF rank = 23 THEN
2606 RETURN 'Postcode Area';
2607 ELSEIF rank = 25 THEN
2608 RETURN 'Postcode Point';
2609 ELSEIF rank = 26 THEN
2610 RETURN 'Street / Major Landmark';
2611 ELSEIF rank = 27 THEN
2612 RETURN 'Minory Street / Path';
2613 ELSEIF rank = 28 THEN
2614 RETURN 'House / Building';
2616 RETURN 'Other: '||rank;
2623 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2629 ELSEIF rank < 2 THEN
2631 ELSEIF rank < 4 THEN
2633 ELSEIF rank = 5 THEN
2635 ELSEIF rank < 8 THEN
2637 ELSEIF rank < 12 THEN
2639 ELSEIF rank < 16 THEN
2641 ELSEIF rank = 16 THEN
2643 ELSEIF rank = 17 THEN
2644 RETURN 'Town / Village / Hamlet';
2645 ELSEIF rank = 20 THEN
2647 ELSEIF rank = 21 THEN
2648 RETURN 'Postcode Area';
2649 ELSEIF rank = 22 THEN
2650 RETURN 'Croft / Farm / Locality / Islet';
2651 ELSEIF rank = 23 THEN
2652 RETURN 'Postcode Area';
2653 ELSEIF rank = 25 THEN
2654 RETURN 'Postcode Point';
2655 ELSEIF rank = 26 THEN
2656 RETURN 'Street / Major Landmark';
2657 ELSEIF rank = 27 THEN
2658 RETURN 'Minory Street / Path';
2659 ELSEIF rank = 28 THEN
2660 RETURN 'House / Building';
2662 RETURN 'Other: '||rank;
2669 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2676 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2677 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2684 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2692 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2694 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2695 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2697 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2705 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2706 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2711 place_centroid GEOMETRY;
2712 out_partition INTEGER;
2713 out_parent_place_id BIGINT;
2715 address_street_word_id INTEGER;
2720 place_centroid := ST_Centroid(pointgeo);
2721 out_partition := get_partition(in_countrycode);
2722 out_parent_place_id := null;
2724 address_street_word_id := get_name_id(make_standard_name(in_street));
2725 IF address_street_word_id IS NOT NULL THEN
2726 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2727 out_parent_place_id := location.place_id;
2731 IF out_parent_place_id IS NULL THEN
2732 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2733 out_parent_place_id := location.place_id;
2737 out_postcode := in_postcode;
2738 IF out_postcode IS NULL THEN
2739 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2741 IF out_postcode IS NULL THEN
2742 out_postcode := getNearestPostcode(out_partition, place_centroid);
2746 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2747 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2748 newpoints := newpoints + 1;
2755 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2762 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2763 IF members[i+1] = member THEN
2764 result := result || members[i];
2773 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2779 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2780 IF members[i+1] = ANY(memberLabels) THEN
2781 RETURN NEXT members[i];
2790 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2791 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2793 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2794 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
2795 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2796 ), '') AS bytea), 'UTF8');
2798 LANGUAGE SQL IMMUTABLE STRICT;
2800 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2804 RETURN decode_url_part(p);
2806 WHEN others THEN return null;
2809 LANGUAGE plpgsql IMMUTABLE;
2811 DROP TYPE wikipedia_article_match CASCADE;
2812 create type wikipedia_article_match as (
2818 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2824 wiki_article_title TEXT;
2825 wiki_article_language TEXT;
2826 result wikipedia_article_match;
2828 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'];
2830 WHILE langs[i] IS NOT NULL LOOP
2831 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2832 IF wiki_article is not null THEN
2833 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2834 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2835 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2836 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2837 wiki_article := replace(wiki_article,' ','_');
2838 IF strpos(wiki_article, ':') IN (3,4) THEN
2839 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2840 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2842 wiki_article_title := trim(wiki_article);
2843 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;
2846 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2847 from wikipedia_article
2848 where language = wiki_article_language and
2849 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2851 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2852 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2853 where wikipedia_redirect.language = wiki_article_language and
2854 (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'\\',''))
2855 order by importance desc limit 1 INTO result;
2857 IF result.language is not null THEN
2868 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2869 RETURNS SETOF GEOMETRY
2883 remainingdepth INTEGER;
2888 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2890 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2891 RETURN NEXT geometry;
2895 remainingdepth := maxdepth - 1;
2896 area := ST_AREA(geometry);
2897 IF remainingdepth < 1 OR area < maxarea THEN
2898 RETURN NEXT geometry;
2902 xmin := st_xmin(geometry);
2903 xmax := st_xmax(geometry);
2904 ymin := st_ymin(geometry);
2905 ymax := st_ymax(geometry);
2906 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2908 -- if the geometry completely covers the box don't bother to slice any more
2909 IF ST_AREA(secbox) = area THEN
2910 RETURN NEXT geometry;
2914 xmid := (xmin+xmax)/2;
2915 ymid := (ymin+ymax)/2;
2918 FOR seg IN 1..4 LOOP
2921 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2924 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2927 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2930 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2933 IF st_intersects(geometry, secbox) THEN
2934 secgeo := st_intersection(geometry, secbox);
2935 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2936 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2937 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2939 RETURN NEXT geo.geom;
2951 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2952 RETURNS SETOF GEOMETRY
2957 -- 10000000000 is ~~ 1x1 degree
2958 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2959 RETURN NEXT geo.geom;
2967 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2971 osmtype character(1);
2975 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2976 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2977 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2978 -- force delete from place/placex by making it a very small geometry
2979 UPDATE place set geometry = ST_SetSRID(ST_Point(0,0), 4326) where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2980 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2987 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2995 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2996 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2997 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2998 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2999 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3000 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3001 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
3002 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3003 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
3009 ELSEIF rank < 18 THEN
3011 ELSEIF rank < 20 THEN
3013 ELSEIF rank = 21 THEN
3015 ELSEIF rank < 24 THEN
3017 ELSEIF rank < 26 THEN
3018 diameter := 0.002; -- 100 to 200 meters
3019 ELSEIF rank < 28 THEN
3020 diameter := 0.001; -- 50 to 100 meters
3022 IF diameter > 0 THEN
3024 -- roads may cause reparenting for >27 rank places
3025 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3026 ELSEIF rank >= 16 THEN
3027 -- up to rank 16, street-less addresses may need reparenting
3028 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
3030 -- for all other places the search terms may change as well
3031 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null);