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);
750 -- find the parant road of an interpolation
751 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
752 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
757 parent_place_id BIGINT;
758 address_street_word_ids INTEGER[];
764 addr_street = street;
767 IF addr_street is null and addr_place is null THEN
768 select nodes from planet_osm_ways where id = wayid INTO waynodes;
769 FOR location IN SELECT placex.street, placex.addr_place from placex
770 where osm_type = 'N' and osm_id = ANY(waynodes)
771 and (placex.street is not null or placex.addr_place is not null)
772 and indexed_status < 100
774 addr_street = location.street;
775 addr_place = location.addr_place;
779 IF addr_street IS NOT NULL THEN
780 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
781 IF address_street_word_ids IS NOT NULL THEN
782 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
783 parent_place_id := location.place_id;
788 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
789 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
790 IF address_street_word_ids IS NOT NULL THEN
791 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
792 parent_place_id := location.place_id;
797 IF parent_place_id is null THEN
798 FOR location IN SELECT place_id FROM placex
799 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
800 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
801 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
802 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
804 parent_place_id := location.place_id;
808 IF parent_place_id is null THEN
812 RETURN parent_place_id;
817 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT,
818 parent_id BIGINT, partition INTEGER,
819 country_code TEXT, geometry_sector INTEGER,
820 defpostalcode TEXT, geom GEOMETRY) RETURNS INTEGER
832 orginalstartnumber INTEGER;
833 originalnumberrange INTEGER;
841 delete from placex where osm_type = 'W' and osm_id = wayid
842 and class = 'place' and type = 'address';
844 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
846 ELSEIF interpolationtype = 'all' THEN
848 ELSEIF interpolationtype ~ '^\d+$' THEN
849 stepsize := interpolationtype::INTEGER;
854 select nodes from planet_osm_ways where id = wayid INTO waynodes;
856 IF array_upper(waynodes, 1) IS NULL THEN
864 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
866 -- If there is a place of a type other than place/house, use that because
867 -- it is guaranteed to be the original node. For place/house types use the
868 -- one with the smallest id because the original node was created first.
869 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
870 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
871 and indexed_status < 100
872 order by (type = 'address'),place_id limit 1 INTO nextnode;
873 IF nextnode.place_id IS NOT NULL THEN
875 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
876 -- Make sure that the point is actually on the line. That might
877 -- be a bit paranoid but ensures that the algorithm still works
878 -- should osm2pgsql attempt to repair geometries.
879 splitline := split_line_on_node(linegeo, nextnode.geometry);
880 sectiongeo := ST_GeometryN(splitline, 1);
881 linegeo := ST_GeometryN(splitline, 2);
883 sectiongeo = linegeo;
885 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
887 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
888 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
889 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
891 IF (startnumber > endnumber) THEN
892 housenum := endnumber;
893 endnumber := startnumber;
894 startnumber := housenum;
895 sectiongeo := ST_Reverse(sectiongeo);
897 orginalstartnumber := startnumber;
898 originalnumberrange := endnumber - startnumber;
900 startnumber := startnumber + stepsize;
901 -- correct for odd/even
902 IF (interpolationtype = 'odd' AND startnumber%2 = 0)
903 OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
904 startnumber := startnumber - 1;
906 endnumber := endnumber - 1;
908 -- keep for compatibility with previous versions
909 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id
910 and place_id != prevnode.place_id and class = 'place'
912 FOR housenum IN startnumber..endnumber BY stepsize LOOP
913 pointgeo := ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float);
914 insert into placex (place_id, partition, osm_type, osm_id,
915 class, type, admin_level, housenumber,
917 country_code, parent_place_id, rank_address, rank_search,
918 indexed_status, indexed_date, geometry_sector,
919 calculated_country_code, centroid, geometry)
920 values (nextval('seq_place'), partition, 'W', wayid,
921 'place', 'address', prevnode.admin_level, housenum,
922 coalesce(prevnode.postcode, defpostalcode),
923 prevnode.country_code, parent_id, 30, 30,
924 0, now(), geometry_sector, country_code,
926 newpoints := newpoints + 1;
927 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
931 -- early break if we are out of line string,
932 -- might happen when a line string loops back on itself
933 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
937 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
938 prevnode := nextnode;
942 --RAISE WARNING 'interpolation points % ',newpoints;
949 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
955 country_code VARCHAR(2);
956 default_language VARCHAR(10);
960 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
962 -- ignore interpolated addresses
963 IF NEW.class = 'place' and NEW.type = 'address' THEN
968 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
969 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
973 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
974 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
975 RAISE WARNING 'invalid geometry %',NEW.osm_id;
979 IF NEW.osm_type = 'R' THEN
980 -- invalid multipolygons can crash postgis, don't even bother to try!
983 NEW.geometry := ST_buffer(NEW.geometry,0);
984 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
985 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
990 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
992 NEW.place_id := nextval('seq_place');
993 NEW.indexed_status := 1; --STATUS_NEW
995 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
997 NEW.partition := get_partition(NEW.calculated_country_code);
998 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1000 -- copy 'name' to or from the default language (if there is a default language)
1001 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1002 default_language := get_country_language_code(NEW.calculated_country_code);
1003 IF default_language IS NOT NULL THEN
1004 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1005 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1006 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1007 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1012 IF NEW.admin_level > 15 THEN
1013 NEW.admin_level := 15;
1016 IF NEW.housenumber IS NOT NULL THEN
1017 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1020 IF NEW.osm_type = 'X' THEN
1021 -- E'X'ternal records should already be in the right format so do nothing
1023 NEW.rank_search := 30;
1024 NEW.rank_address := NEW.rank_search;
1026 -- By doing in postgres we have the country available to us - currently only used for postcode
1027 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
1029 IF NEW.postcode IS NULL THEN
1030 -- most likely just a part of a multipolygon postcode boundary, throw it away
1034 NEW.name := hstore('ref', NEW.postcode);
1036 IF NEW.calculated_country_code = 'gb' THEN
1038 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1039 NEW.rank_search := 25;
1040 NEW.rank_address := 5;
1041 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1042 NEW.rank_search := 23;
1043 NEW.rank_address := 5;
1044 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1045 NEW.rank_search := 21;
1046 NEW.rank_address := 5;
1049 ELSEIF NEW.calculated_country_code = 'sg' THEN
1051 IF NEW.postcode ~ '^([0-9]{6})$' THEN
1052 NEW.rank_search := 25;
1053 NEW.rank_address := 11;
1056 ELSEIF NEW.calculated_country_code = 'de' THEN
1058 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1059 NEW.rank_search := 21;
1060 NEW.rank_address := 11;
1064 -- Guess at the postcode format and coverage (!)
1065 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1066 NEW.rank_search := 21;
1067 NEW.rank_address := 11;
1069 -- Does it look splitable into and area and local code?
1070 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1072 IF postcode IS NOT NULL THEN
1073 NEW.rank_search := 25;
1074 NEW.rank_address := 11;
1075 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1076 NEW.rank_search := 21;
1077 NEW.rank_address := 11;
1082 ELSEIF NEW.class = 'place' THEN
1083 IF NEW.type in ('continent') THEN
1084 NEW.rank_search := 2;
1085 NEW.rank_address := NEW.rank_search;
1086 NEW.calculated_country_code := NULL;
1087 ELSEIF NEW.type in ('sea') THEN
1088 NEW.rank_search := 2;
1089 NEW.rank_address := 0;
1090 NEW.calculated_country_code := NULL;
1091 ELSEIF NEW.type in ('country') THEN
1092 NEW.rank_search := 4;
1093 NEW.rank_address := NEW.rank_search;
1094 ELSEIF NEW.type in ('state') THEN
1095 NEW.rank_search := 8;
1096 NEW.rank_address := NEW.rank_search;
1097 ELSEIF NEW.type in ('region') THEN
1098 NEW.rank_search := 18; -- dropped from previous value of 10
1099 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1100 ELSEIF NEW.type in ('county') THEN
1101 NEW.rank_search := 12;
1102 NEW.rank_address := NEW.rank_search;
1103 ELSEIF NEW.type in ('city') THEN
1104 NEW.rank_search := 16;
1105 NEW.rank_address := NEW.rank_search;
1106 ELSEIF NEW.type in ('island') THEN
1107 NEW.rank_search := 17;
1108 NEW.rank_address := 0;
1109 ELSEIF NEW.type in ('town') THEN
1110 NEW.rank_search := 18;
1111 NEW.rank_address := 16;
1112 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1113 NEW.rank_search := 19;
1114 NEW.rank_address := 16;
1115 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1116 NEW.rank_search := 20;
1117 NEW.rank_address := NEW.rank_search;
1118 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1119 NEW.rank_search := 20;
1120 NEW.rank_address := 0;
1121 -- Irish townlands, tagged as place=locality and locality=townland
1122 IF (NEW.extratags -> 'locality') = 'townland' THEN
1123 NEW.rank_address := 20;
1125 ELSEIF NEW.type in ('neighbourhood') THEN
1126 NEW.rank_search := 22;
1127 NEW.rank_address := 22;
1128 ELSEIF NEW.type in ('house','building') THEN
1129 NEW.rank_search := 30;
1130 NEW.rank_address := NEW.rank_search;
1131 ELSEIF NEW.type in ('houses') THEN
1132 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1133 NEW.rank_search := 28;
1134 NEW.rank_address := 0;
1137 ELSEIF NEW.class = 'boundary' THEN
1138 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1139 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1142 NEW.rank_search := NEW.admin_level * 2;
1143 IF NEW.type = 'administrative' THEN
1144 NEW.rank_address := NEW.rank_search;
1146 NEW.rank_address := 0;
1148 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1149 NEW.rank_search := 22;
1150 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1151 NEW.rank_address := NEW.rank_search;
1153 NEW.rank_address := 0;
1155 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1156 NEW.rank_search := 18;
1157 NEW.rank_address := 0;
1158 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1159 NEW.rank_search := 4;
1160 NEW.rank_address := NEW.rank_search;
1161 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1163 -- any feature more than 5 square miles is probably worth indexing
1164 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1165 NEW.rank_search := 22;
1166 NEW.rank_address := 0;
1167 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1168 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1169 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1171 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1173 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1175 ELSEIF NEW.class = 'waterway' THEN
1176 IF NEW.osm_type = 'R' THEN
1177 NEW.rank_search := 16;
1179 NEW.rank_search := 17;
1181 NEW.rank_address := 0;
1182 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
1183 NEW.rank_search := 27;
1184 NEW.rank_address := NEW.rank_search;
1185 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1186 NEW.rank_search := 26;
1187 NEW.rank_address := NEW.rank_search;
1188 ELSEIF NEW.class = 'mountain_pass' THEN
1189 NEW.rank_search := 20;
1190 NEW.rank_address := 0;
1195 IF NEW.rank_search > 30 THEN
1196 NEW.rank_search := 30;
1199 IF NEW.rank_address > 30 THEN
1200 NEW.rank_address := 30;
1203 IF (NEW.extratags -> 'capital') = 'yes' THEN
1204 NEW.rank_search := NEW.rank_search - 1;
1207 -- a country code make no sense below rank 4 (country)
1208 IF NEW.rank_search < 4 THEN
1209 NEW.calculated_country_code := NULL;
1212 -- Block import below rank 22
1213 -- IF NEW.rank_search > 22 THEN
1217 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1219 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1221 IF NEW.rank_address > 0 THEN
1222 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1223 -- Performance: We just can't handle re-indexing for country level changes
1224 IF st_area(NEW.geometry) < 1 THEN
1225 -- mark items within the geometry for re-indexing
1226 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1228 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1229 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1230 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));
1231 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1232 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));
1235 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1237 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1238 IF NEW.type='postcode' THEN
1240 ELSEIF NEW.rank_search < 16 THEN
1242 ELSEIF NEW.rank_search < 18 THEN
1244 ELSEIF NEW.rank_search < 20 THEN
1246 ELSEIF NEW.rank_search = 21 THEN
1248 ELSEIF NEW.rank_search < 24 THEN
1250 ELSEIF NEW.rank_search < 26 THEN
1251 diameter := 0.002; -- 100 to 200 meters
1252 ELSEIF NEW.rank_search < 28 THEN
1253 diameter := 0.001; -- 50 to 100 meters
1255 IF diameter > 0 THEN
1256 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1257 IF NEW.rank_search >= 26 THEN
1258 -- roads may cause reparenting for >27 rank places
1259 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1260 ELSEIF NEW.rank_search >= 16 THEN
1261 -- up to rank 16, street-less addresses may need reparenting
1262 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);
1264 -- for all other places the search terms may change as well
1265 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);
1272 -- add to tables for special search
1273 -- Note: won't work on initial import because the classtype tables
1274 -- do not yet exist. It won't hurt either.
1275 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1276 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1278 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1279 USING NEW.place_id, ST_Centroid(NEW.geometry);
1283 -- IF NEW.rank_search < 26 THEN
1284 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1293 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1298 place_centroid GEOMETRY;
1300 search_maxdistance FLOAT[];
1301 search_mindistance FLOAT[];
1302 address_havelevel BOOLEAN[];
1309 relation_members TEXT[];
1311 linkedplacex RECORD;
1312 search_diameter FLOAT;
1313 search_prevdiameter FLOAT;
1314 search_maxrank INTEGER;
1315 address_maxrank INTEGER;
1316 address_street_word_id INTEGER;
1317 address_street_word_ids INTEGER[];
1318 parent_place_id_rank BIGINT;
1323 location_rank_search INTEGER;
1324 location_distance FLOAT;
1325 location_parent GEOMETRY;
1326 location_isaddress BOOLEAN;
1327 location_keywords INTEGER[];
1331 default_language TEXT;
1332 name_vector INTEGER[];
1333 nameaddress_vector INTEGER[];
1335 linked_node_id BIGINT;
1341 IF OLD.indexed_status = 100 THEN
1342 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1343 delete from placex where place_id = OLD.place_id;
1347 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1351 -- ignore interpolated addresses
1352 IF NEW.class = 'place' and NEW.type = 'address' THEN
1356 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1358 --RAISE WARNING '%',NEW.place_id;
1359 --RAISE WARNING '%', NEW;
1361 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1362 -- Silently do nothing
1366 -- TODO: this test is now redundant?
1367 IF OLD.indexed_status != 0 THEN
1369 NEW.indexed_date = now();
1371 result := deleteSearchName(NEW.partition, NEW.place_id);
1372 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1373 result := deleteRoad(NEW.partition, NEW.place_id);
1374 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1375 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1377 IF NEW.linked_place_id is not null THEN
1381 -- Speed up searches - just use the centroid of the feature
1382 -- cheaper but less acurate
1383 place_centroid := ST_PointOnSurface(NEW.geometry);
1384 NEW.centroid := null;
1386 -- recalculate country and partition
1387 IF NEW.rank_search = 4 THEN
1388 -- for countries, believe the mapped country code,
1389 -- so that we remain in the right partition if the boundaries
1391 NEW.partition := get_partition(lower(NEW.country_code));
1392 IF NEW.partition = 0 THEN
1393 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1394 NEW.partition := get_partition(NEW.calculated_country_code);
1396 NEW.calculated_country_code := lower(NEW.country_code);
1399 IF NEW.rank_search > 4 THEN
1400 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1401 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1403 NEW.calculated_country_code := NULL;
1405 NEW.partition := get_partition(NEW.calculated_country_code);
1407 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1410 IF NEW.class = 'place' AND NEW.type = 'houses'THEN
1411 IF NEW.osm_type = 'W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1412 NEW.parent_place_id := get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1413 NEW.partition, place_centroid, NEW.geometry);
1414 i := create_interpolation(NEW.osm_id, NEW.housenumber, NEW.parent_place_id,
1415 NEW.partition, NEW.calculated_country_code,
1416 NEW.geometry_sector, NEW.postcode, NEW.geometry);
1421 -- waterway ways are linked when they are part of a relation and have the same class/type
1422 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1423 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1425 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1426 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1427 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1428 FOR linked_node_id IN SELECT place_id FROM placex
1429 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1430 and class = NEW.class and type = NEW.type
1431 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1433 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1440 -- Adding ourselves to the list simplifies address calculations later
1441 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1443 -- What level are we searching from
1444 search_maxrank := NEW.rank_search;
1446 -- Thought this wasn't needed but when we add new languages to the country_name table
1447 -- we need to update the existing names
1448 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1449 default_language := get_country_language_code(NEW.calculated_country_code);
1450 IF default_language IS NOT NULL THEN
1451 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1452 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1453 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1454 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1459 -- Initialise the name vector using our name
1460 name_vector := make_keywords(NEW.name);
1461 nameaddress_vector := '{}'::int[];
1463 -- some tag combinations add a special id for search
1464 tagpairid := get_tagpair(NEW.class,NEW.type);
1465 IF tagpairid IS NOT NULL THEN
1466 name_vector := name_vector + tagpairid;
1470 address_havelevel[i] := false;
1473 NEW.importance := null;
1474 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1475 IF NEW.importance IS NULL THEN
1476 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;
1479 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1481 -- For low level elements we inherit from our parent road
1482 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1484 --RAISE WARNING 'finding street for %', NEW;
1486 -- We won't get a better centroid, besides these places are too small to care
1487 NEW.centroid := place_centroid;
1489 NEW.parent_place_id := null;
1491 -- if we have a POI and there is no address information,
1492 -- see if we can get it from a surrounding building
1493 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1494 AND NEW.housenumber IS NULL THEN
1495 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1496 and (housenumber is not null or street is not null or addr_place is not null)
1497 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1500 NEW.housenumber := location.housenumber;
1501 NEW.street := location.street;
1502 NEW.addr_place := location.addr_place;
1506 -- We have to find our parent road.
1507 -- Copy data from linked items (points on ways, addr:street links, relations)
1509 -- Is this object part of a relation?
1510 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1512 -- At the moment we only process one type of relation - associatedStreet
1513 IF relation.tags @> ARRAY['associatedStreet'] THEN
1514 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1515 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1516 --RAISE WARNING 'node in relation %',relation;
1517 SELECT place_id from placex where osm_type = 'W'
1518 and osm_id = substring(relation.members[i],2,200)::bigint
1519 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1526 -- Note that addr:street links can only be indexed once the street itself is indexed
1527 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1528 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1529 IF address_street_word_ids IS NOT NULL THEN
1530 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1531 NEW.parent_place_id := location.place_id;
1536 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1537 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1538 IF address_street_word_ids IS NOT NULL THEN
1539 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1540 NEW.parent_place_id := location.place_id;
1545 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1547 --RAISE WARNING 'x1';
1548 -- Is this node part of a way?
1549 FOR location IN select p.* from placex p, planet_osm_ways w
1550 where p.osm_type = 'W' and p.rank_search >= 26
1551 and p.geometry && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes)
1553 --RAISE WARNING '%', location;
1554 -- Way IS a road then we are on it - that must be our road
1555 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1556 --RAISE WARNING 'node in way that is a street %',location;
1557 NEW.parent_place_id := location.place_id;
1560 -- If this way is a street interpolation line then it is probably as good as we are going to get
1561 IF NEW.parent_place_id IS NULL AND location.class = 'place' and location.type='houses' THEN
1562 NEW.parent_place_id := location.parent_place_id;
1565 -- Is the WAY part of a relation
1566 IF NEW.parent_place_id IS NULL THEN
1567 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1569 -- At the moment we only process one type of relation - associatedStreet
1570 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1571 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1572 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1573 --RAISE WARNING 'node in way that is in a relation %',relation;
1574 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1575 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1582 -- If the way mentions a street or place address, try that for parenting.
1583 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1584 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1585 IF address_street_word_ids IS NOT NULL THEN
1586 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1587 NEW.parent_place_id := linkedplacex.place_id;
1592 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1593 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1594 IF address_street_word_ids IS NOT NULL THEN
1595 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1596 NEW.parent_place_id := linkedplacex.place_id;
1605 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1606 -- Still nothing, just use the nearest road
1607 IF NEW.parent_place_id IS NULL THEN
1608 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1609 NEW.parent_place_id := location.place_id;
1614 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1616 -- If we didn't find any road fallback to standard method
1617 IF NEW.parent_place_id IS NOT NULL THEN
1619 -- Add the street to the address as zero distance to force to front of list
1620 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1621 address_havelevel[26] := true;
1623 -- Import address details from parent, reclculating distance in process
1624 -- 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
1625 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1626 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1628 -- Get the details of the parent road
1629 select * from search_name where place_id = NEW.parent_place_id INTO location;
1630 NEW.calculated_country_code := location.country_code;
1632 --RAISE WARNING '%', NEW.name;
1633 -- If there is no name it isn't searchable, don't bother to create a search record
1634 IF NEW.name is NULL THEN
1638 -- Merge address from parent
1639 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1640 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1642 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1643 -- Just be happy with inheriting from parent road only
1645 IF NEW.rank_search <= 25 THEN
1646 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1649 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);
1656 -- RAISE WARNING ' INDEXING Started:';
1657 -- RAISE WARNING ' INDEXING: %',NEW;
1659 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1661 -- see if we have any special relation members
1662 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1664 -- RAISE WARNING 'get_osm_rel_members, label';
1665 IF relation_members IS NOT NULL THEN
1666 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1668 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1669 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1671 -- If we don't already have one use this as the centre point of the geometry
1672 IF NEW.centroid IS NULL THEN
1673 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1676 -- merge in the label name, re-init word vector
1677 IF NOT linkedPlacex.name IS NULL THEN
1678 NEW.name := linkedPlacex.name || NEW.name;
1679 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1682 -- merge in extra tags
1683 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1685 -- mark the linked place (excludes from search results)
1686 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1688 -- keep a note of the node id in case we need it for wikipedia in a bit
1689 linked_node_id := linkedPlacex.osm_id;
1694 IF NEW.centroid IS NULL THEN
1696 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1698 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1699 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1701 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1702 -- But that can be fixed by explicitly setting the label in the data
1703 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1704 AND NEW.rank_address = linkedPlacex.rank_address THEN
1706 -- If we don't already have one use this as the centre point of the geometry
1707 IF NEW.centroid IS NULL THEN
1708 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1711 -- merge in the name, re-init word vector
1712 IF NOT linkedPlacex.name IS NULL THEN
1713 NEW.name := linkedPlacex.name || NEW.name;
1714 name_vector := make_keywords(NEW.name);
1717 -- merge in extra tags
1718 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1720 -- mark the linked place (excludes from search results)
1721 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1723 -- keep a note of the node id in case we need it for wikipedia in a bit
1724 linked_node_id := linkedPlacex.osm_id;
1736 -- Name searches can be done for ways as well as relations
1737 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1739 -- not found one yet? how about doing a name search
1740 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1742 FOR linkedPlacex IN select placex.* from placex WHERE
1743 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1744 AND placex.rank_address = NEW.rank_address
1745 AND placex.place_id != NEW.place_id
1746 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1747 AND st_covers(NEW.geometry, placex.geometry)
1750 -- If we don't already have one use this as the centre point of the geometry
1751 IF NEW.centroid IS NULL THEN
1752 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1755 -- merge in the name, re-init word vector
1756 NEW.name := linkedPlacex.name || NEW.name;
1757 name_vector := make_keywords(NEW.name);
1759 -- merge in extra tags
1760 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1762 -- mark the linked place (excludes from search results)
1763 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1765 -- keep a note of the node id in case we need it for wikipedia in a bit
1766 linked_node_id := linkedPlacex.osm_id;
1770 IF NEW.centroid IS NOT NULL THEN
1771 place_centroid := NEW.centroid;
1772 -- Place might have had only a name tag before but has now received translations
1773 -- from the linked place. Make sure a name tag for the default language exists in
1775 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1776 default_language := get_country_language_code(NEW.calculated_country_code);
1777 IF default_language IS NOT NULL THEN
1778 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1779 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1780 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1781 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1787 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1788 IF NEW.importance is null THEN
1789 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1791 -- Still null? how about looking it up by the node id
1792 IF NEW.importance IS NULL THEN
1793 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;
1798 -- make sure all names are in the word table
1799 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1800 perform create_country(NEW.name, lower(NEW.country_code));
1803 NEW.parent_place_id = 0;
1804 parent_place_id_rank = 0;
1806 -- convert isin to array of tokenids
1807 isin_tokens := '{}'::int[];
1808 IF NEW.isin IS NOT NULL THEN
1809 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1810 IF array_upper(isin, 1) IS NOT NULL THEN
1811 FOR i IN 1..array_upper(isin, 1) LOOP
1812 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1813 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1814 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1815 isin_tokens := isin_tokens || address_street_word_id;
1818 -- merge word into address vector
1819 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1820 IF address_street_word_id IS NOT NULL THEN
1821 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1826 IF NEW.postcode IS NOT NULL THEN
1827 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1828 IF array_upper(isin, 1) IS NOT NULL THEN
1829 FOR i IN 1..array_upper(isin, 1) LOOP
1830 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1831 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1832 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1833 isin_tokens := isin_tokens || address_street_word_id;
1836 -- merge into address vector
1837 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1838 IF address_street_word_id IS NOT NULL THEN
1839 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1845 -- for the USA we have an additional address table. Merge in zip codes from there too
1846 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1847 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1848 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1849 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1850 isin_tokens := isin_tokens || address_street_word_id;
1852 -- also merge in the single word version
1853 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1854 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1858 -- RAISE WARNING 'ISIN: %', isin_tokens;
1860 -- Process area matches
1861 location_rank_search := 0;
1862 location_distance := 0;
1863 location_parent := NULL;
1864 -- added ourself as address already
1865 address_havelevel[NEW.rank_address] := true;
1866 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1867 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1869 --RAISE WARNING ' AREA: %',location;
1871 IF location.rank_address != location_rank_search THEN
1872 location_rank_search := location.rank_address;
1873 IF location.isguess THEN
1874 location_distance := location.distance * 1.5;
1876 IF location.rank_address <= 12 THEN
1877 -- for county and above, if we have an area consider that exact
1878 -- (It would be nice to relax the constraint for places close to
1879 -- the boundary but we'd need the exact geometry for that. Too
1881 location_distance = 0;
1883 -- Below county level remain slightly fuzzy.
1884 location_distance := location.distance * 0.5;
1888 CONTINUE WHEN location.keywords <@ location_keywords;
1891 IF location.distance < location_distance OR NOT location.isguess THEN
1892 location_keywords := location.keywords;
1894 location_isaddress := NOT address_havelevel[location.rank_address];
1895 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1896 location_isaddress := ST_Contains(location_parent,location.centroid);
1899 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1900 -- Add it to the list of search terms
1901 IF location.rank_search > 4 THEN
1902 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1904 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1906 IF location_isaddress THEN
1908 address_havelevel[location.rank_address] := true;
1909 IF NOT location.isguess THEN
1910 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1913 IF location.rank_address > parent_place_id_rank THEN
1914 NEW.parent_place_id = location.place_id;
1915 parent_place_id_rank = location.rank_address;
1920 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1926 -- try using the isin value to find parent places
1927 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1928 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1929 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1930 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1932 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1934 --RAISE WARNING ' ISIN: %',location;
1936 IF location.rank_search > 4 THEN
1937 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1938 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1939 address_havelevel[location.rank_address] := true;
1941 IF location.rank_address > parent_place_id_rank THEN
1942 NEW.parent_place_id = location.place_id;
1943 parent_place_id_rank = location.rank_address;
1953 -- for long ways we should add search terms for the entire length
1954 IF st_length(NEW.geometry) > 0.05 THEN
1956 location_rank_search := 0;
1957 location_distance := 0;
1959 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1961 IF location.rank_address != location_rank_search THEN
1962 location_rank_search := location.rank_address;
1963 location_distance := location.distance * 1.5;
1966 IF location.rank_search > 4 AND location.distance < location_distance THEN
1968 -- Add it to the list of search terms
1969 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1970 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1978 -- if we have a name add this to the name search table
1979 IF NEW.name IS NOT NULL THEN
1981 IF NEW.rank_search <= 25 THEN
1982 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1985 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1986 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1989 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);
1993 -- If we've not managed to pick up a better one - default centroid
1994 IF NEW.centroid IS NULL THEN
1995 NEW.centroid := place_centroid;
2005 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
2011 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
2013 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
2014 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
2015 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
2016 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
2018 IF OLD.rank_address < 30 THEN
2020 -- mark everything linked to this place for re-indexing
2021 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
2022 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
2023 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
2025 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
2026 DELETE FROM place_addressline where address_place_id = OLD.place_id;
2028 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
2029 b := deleteRoad(OLD.partition, OLD.place_id);
2031 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
2032 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
2033 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
2037 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2039 IF OLD.rank_address < 26 THEN
2040 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2043 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2045 IF OLD.name is not null THEN
2046 b := deleteSearchName(OLD.partition, OLD.place_id);
2049 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2051 DELETE FROM place_addressline where place_id = OLD.place_id;
2053 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2055 -- remove from tables for special search
2056 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2057 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2059 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2062 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2070 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2076 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2078 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2079 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2080 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;
2082 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2088 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;
2090 -- interpolations are special
2091 IF OLD.class = 'place' and OLD.type = 'houses' THEN
2092 UPDATE placex set indexed_status = 100 where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = 'place' and type = 'address';
2101 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2106 existingplacex RECORD;
2107 existinggeometry GEOMETRY;
2108 existingplace_id BIGINT;
2113 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2114 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2116 IF FALSE and NEW.osm_type = 'R' THEN
2117 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;
2118 --DEBUG: RAISE WARNING '%', existingplacex;
2121 -- Just block these - lots and pointless
2122 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2123 -- if the name tag was removed, older versions might still be lurking in the place table
2124 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2128 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
2129 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2130 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2131 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2135 -- Patch in additional country names
2136 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2137 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2140 -- Have we already done this place?
2141 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;
2143 -- Get the existing place_id
2144 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;
2146 -- Handle a place changing type by removing the old data
2147 -- My generated 'place' types are causing havok because they overlap with real keys
2148 -- TODO: move them to their own special purpose key/class to avoid collisions
2149 IF existing.osm_type IS NULL THEN
2150 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2153 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2154 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2157 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2158 AND st_area(existing.geometry) > 0.02
2159 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2160 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2162 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2163 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2167 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2168 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2170 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2171 IF existingplacex.osm_type IS NULL OR
2172 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2175 IF existingplacex.osm_type IS NOT NULL THEN
2176 -- sanity check: ignore admin_level changes on places with too many active children
2177 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2178 --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;
2179 --LIMIT INDEXING: IF i > 100000 THEN
2180 --LIMIT INDEXING: RETURN null;
2181 --LIMIT INDEXING: END IF;
2184 IF existing.osm_type IS NOT NULL THEN
2185 -- pathological case caused by the triggerless copy into place during initial import
2186 -- force delete even for large areas, it will be reinserted later
2187 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;
2188 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2191 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2192 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2193 street, addr_place, isin, postcode, country_code, extratags, geometry)
2194 values (NEW.osm_type
2210 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2215 -- Various ways to do the update
2217 -- Debug, what's changed?
2219 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2220 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2222 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2223 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2225 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2226 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2228 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2229 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2231 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2232 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2234 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2235 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2237 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2238 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2242 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2243 IF existing.geometry::text != NEW.geometry::text
2244 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2245 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2248 -- Get the version of the geometry actually used (in placex table)
2249 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;
2251 -- Performance limit
2252 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2254 -- 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
2255 update placex set indexed_status = 2 where indexed_status = 0 and
2256 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2257 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2258 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2260 update placex set indexed_status = 2 where indexed_status = 0 and
2261 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2262 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2263 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2269 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2270 IF FALSE AND existingplacex.rank_search < 26
2271 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2272 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2273 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2274 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2275 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2276 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2277 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2280 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2282 IF st_area(NEW.geometry) < 0.5 THEN
2283 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2284 and placex.place_id = place_addressline.place_id and indexed_status = 0
2285 and (rank_search < 28 or name is not null);
2292 -- Anything else has changed - reindex the lot
2293 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2294 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2295 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2296 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2297 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2298 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2299 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2301 -- performance, can't take the load of re-indexing a whole country / huge area
2302 IF st_area(NEW.geometry) < 0.5 THEN
2303 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2304 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2311 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2312 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2313 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2314 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2315 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2316 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2317 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2318 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2319 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2320 OR existing.geometry::text != NEW.geometry::text
2325 housenumber = NEW.housenumber,
2326 street = NEW.street,
2327 addr_place = NEW.addr_place,
2329 postcode = NEW.postcode,
2330 country_code = NEW.country_code,
2331 extratags = NEW.extratags,
2332 admin_level = NEW.admin_level,
2333 geometry = NEW.geometry
2334 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2336 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2337 IF NEW.postcode IS NULL THEN
2338 -- postcode was deleted, no longer retain in placex
2339 DELETE FROM placex where place_id = existingplacex.place_id;
2343 NEW.name := hstore('ref', NEW.postcode);
2348 housenumber = NEW.housenumber,
2349 street = NEW.street,
2350 addr_place = NEW.addr_place,
2352 postcode = NEW.postcode,
2353 country_code = NEW.country_code,
2354 parent_place_id = null,
2355 extratags = NEW.extratags,
2356 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2358 geometry = NEW.geometry
2359 where place_id = existingplacex.place_id;
2363 -- for interpolations invalidate all nodes on the line
2364 IF NEW.class = 'place' and NEW.type = 'houses' and NEW.osm_type = 'W' THEN
2365 update placex p set indexed_status = 2 from planet_osm_ways w where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2368 -- Abort the add (we modified the existing place instead)
2372 $$ LANGUAGE plpgsql;
2374 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2381 IF name is null THEN
2385 search := languagepref;
2387 FOR j IN 1..array_upper(search, 1) LOOP
2388 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2389 return trim(name->search[j]);
2393 -- anything will do as a fallback - just take the first name type thing there is
2394 search := avals(name);
2398 LANGUAGE plpgsql IMMUTABLE;
2401 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2412 search := ARRAY['ref'];
2415 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2418 select rank_address,name,distance,length(name::text) as namelength
2419 from place_addressline join placex on (address_place_id = placex.place_id)
2420 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2421 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2423 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2424 FOR j IN 1..array_upper(search, 1) LOOP
2425 FOR k IN 1..array_upper(location.name, 1) LOOP
2426 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
2427 result[(100 - location.rank_address)] := trim(location.name[k].value);
2428 found := location.rank_address;
2435 RETURN array_to_string(result,', ');
2440 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2452 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2453 currresult := trim(get_name_by_language(location.name, languagepref));
2454 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2455 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2456 prevresult := currresult;
2460 RETURN array_to_string(result,', ');
2465 DROP TYPE IF EXISTS addressline CASCADE;
2466 create type addressline as (
2473 admin_level INTEGER,
2476 rank_address INTEGER,
2480 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2483 for_place_id BIGINT;
2488 countrylocation RECORD;
2489 searchcountrycode varchar(2);
2490 searchhousenumber TEXT;
2491 searchhousename HSTORE;
2492 searchrankaddress INTEGER;
2493 searchpostcode TEXT;
2500 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2501 WHERE place_id = in_place_id
2502 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2504 IF for_place_id IS NULL THEN
2505 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2506 WHERE place_id = in_place_id
2507 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2510 IF for_place_id IS NULL THEN
2511 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2512 WHERE place_id = in_place_id and rank_address = 30
2513 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2516 IF for_place_id IS NULL THEN
2517 for_place_id := in_place_id;
2518 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2519 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2522 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2525 hadcountry := false;
2527 select placex.place_id, osm_type, osm_id,
2528 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2529 class, type, admin_level, true as fromarea, true as isaddress,
2530 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2531 0 as distance, calculated_country_code, postcode
2533 where place_id = for_place_id
2535 --RAISE WARNING '%',location;
2536 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2537 searchcountrycode := location.calculated_country_code;
2539 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2540 location.isaddress := FALSE;
2542 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2543 searchpostcode := location.postcode;
2545 IF location.rank_address = 4 AND location.isaddress THEN
2548 IF location.rank_address < 4 AND NOT hadcountry THEN
2549 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2550 IF countryname IS NOT NULL THEN
2551 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2552 RETURN NEXT countrylocation;
2555 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2556 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2557 location.distance)::addressline;
2558 RETURN NEXT countrylocation;
2559 found := location.rank_address;
2563 select placex.place_id, osm_type, osm_id,
2564 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2565 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2566 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2567 admin_level, fromarea, isaddress,
2568 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,
2569 distance,calculated_country_code,postcode
2570 from place_addressline join placex on (address_place_id = placex.place_id)
2571 where place_addressline.place_id = for_place_id
2572 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2573 and address_place_id != for_place_id
2574 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2575 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2577 --RAISE WARNING '%',location;
2578 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2579 searchcountrycode := location.calculated_country_code;
2581 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2582 location.isaddress := FALSE;
2584 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2585 searchpostcode := location.postcode;
2587 IF location.rank_address = 4 AND location.isaddress THEN
2590 IF location.rank_address < 4 AND NOT hadcountry THEN
2591 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2592 IF countryname IS NOT NULL THEN
2593 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2594 RETURN NEXT countrylocation;
2597 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2598 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2599 location.distance)::addressline;
2600 RETURN NEXT countrylocation;
2601 found := location.rank_address;
2605 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2606 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2607 IF countryname IS NOT NULL THEN
2608 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2609 RETURN NEXT location;
2613 IF searchcountrycode IS NOT NULL THEN
2614 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2615 RETURN NEXT location;
2618 IF searchhousename IS NOT NULL THEN
2619 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2620 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2621 RETURN NEXT location;
2624 IF searchhousenumber IS NOT NULL THEN
2625 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2626 RETURN NEXT location;
2629 IF searchpostcode IS NOT NULL THEN
2630 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2631 RETURN NEXT location;
2640 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2643 numfeatures integer;
2647 housenumber = place.housenumber,
2648 street = place.street,
2649 addr_place = place.addr_place,
2651 postcode = place.postcode,
2652 country_code = place.country_code,
2653 parent_place_id = null
2655 where placex.place_id = search_place_id
2656 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2657 and place.class = placex.class and place.type = placex.type;
2658 update placex set indexed_status = 2 where place_id = search_place_id;
2659 update placex set indexed_status = 0 where place_id = search_place_id;
2665 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2671 ELSEIF rank < 4 THEN
2673 ELSEIF rank < 8 THEN
2675 ELSEIF rank < 12 THEN
2677 ELSEIF rank < 16 THEN
2679 ELSEIF rank = 16 THEN
2681 ELSEIF rank = 17 THEN
2682 RETURN 'Town / Island';
2683 ELSEIF rank = 18 THEN
2684 RETURN 'Village / Hamlet';
2685 ELSEIF rank = 20 THEN
2687 ELSEIF rank = 21 THEN
2688 RETURN 'Postcode Area';
2689 ELSEIF rank = 22 THEN
2690 RETURN 'Croft / Farm / Locality / Islet';
2691 ELSEIF rank = 23 THEN
2692 RETURN 'Postcode Area';
2693 ELSEIF rank = 25 THEN
2694 RETURN 'Postcode Point';
2695 ELSEIF rank = 26 THEN
2696 RETURN 'Street / Major Landmark';
2697 ELSEIF rank = 27 THEN
2698 RETURN 'Minory Street / Path';
2699 ELSEIF rank = 28 THEN
2700 RETURN 'House / Building';
2702 RETURN 'Other: '||rank;
2709 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2715 ELSEIF rank < 2 THEN
2717 ELSEIF rank < 4 THEN
2719 ELSEIF rank = 5 THEN
2721 ELSEIF rank < 8 THEN
2723 ELSEIF rank < 12 THEN
2725 ELSEIF rank < 16 THEN
2727 ELSEIF rank = 16 THEN
2729 ELSEIF rank = 17 THEN
2730 RETURN 'Town / Village / Hamlet';
2731 ELSEIF rank = 20 THEN
2733 ELSEIF rank = 21 THEN
2734 RETURN 'Postcode Area';
2735 ELSEIF rank = 22 THEN
2736 RETURN 'Croft / Farm / Locality / Islet';
2737 ELSEIF rank = 23 THEN
2738 RETURN 'Postcode Area';
2739 ELSEIF rank = 25 THEN
2740 RETURN 'Postcode Point';
2741 ELSEIF rank = 26 THEN
2742 RETURN 'Street / Major Landmark';
2743 ELSEIF rank = 27 THEN
2744 RETURN 'Minory Street / Path';
2745 ELSEIF rank = 28 THEN
2746 RETURN 'House / Building';
2748 RETURN 'Other: '||rank;
2755 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2762 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2763 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2770 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2778 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2780 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2781 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2783 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2791 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2792 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2797 place_centroid GEOMETRY;
2798 out_partition INTEGER;
2799 out_parent_place_id BIGINT;
2801 address_street_word_id INTEGER;
2806 place_centroid := ST_Centroid(pointgeo);
2807 out_partition := get_partition(in_countrycode);
2808 out_parent_place_id := null;
2810 address_street_word_id := get_name_id(make_standard_name(in_street));
2811 IF address_street_word_id IS NOT NULL THEN
2812 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2813 out_parent_place_id := location.place_id;
2817 IF out_parent_place_id IS NULL THEN
2818 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2819 out_parent_place_id := location.place_id;
2823 out_postcode := in_postcode;
2824 IF out_postcode IS NULL THEN
2825 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2827 IF out_postcode IS NULL THEN
2828 out_postcode := getNearestPostcode(out_partition, place_centroid);
2832 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2833 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2834 newpoints := newpoints + 1;
2841 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2848 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2849 IF members[i+1] = member THEN
2850 result := result || members[i];
2859 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2865 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2866 IF members[i+1] = ANY(memberLabels) THEN
2867 RETURN NEXT members[i];
2876 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2877 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2879 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2880 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
2881 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2882 ), '') AS bytea), 'UTF8');
2884 LANGUAGE SQL IMMUTABLE STRICT;
2886 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2890 RETURN decode_url_part(p);
2892 WHEN others THEN return null;
2895 LANGUAGE plpgsql IMMUTABLE;
2897 DROP TYPE wikipedia_article_match CASCADE;
2898 create type wikipedia_article_match as (
2904 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2910 wiki_article_title TEXT;
2911 wiki_article_language TEXT;
2912 result wikipedia_article_match;
2914 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'];
2916 WHILE langs[i] IS NOT NULL LOOP
2917 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2918 IF wiki_article is not null THEN
2919 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2920 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2921 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2922 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2923 wiki_article := replace(wiki_article,' ','_');
2924 IF strpos(wiki_article, ':') IN (3,4) THEN
2925 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2926 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2928 wiki_article_title := trim(wiki_article);
2929 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;
2932 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2933 from wikipedia_article
2934 where language = wiki_article_language and
2935 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2937 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2938 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2939 where wikipedia_redirect.language = wiki_article_language and
2940 (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'\\',''))
2941 order by importance desc limit 1 INTO result;
2943 IF result.language is not null THEN
2954 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2955 RETURNS SETOF GEOMETRY
2969 remainingdepth INTEGER;
2974 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2976 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2977 RETURN NEXT geometry;
2981 remainingdepth := maxdepth - 1;
2982 area := ST_AREA(geometry);
2983 IF remainingdepth < 1 OR area < maxarea THEN
2984 RETURN NEXT geometry;
2988 xmin := st_xmin(geometry);
2989 xmax := st_xmax(geometry);
2990 ymin := st_ymin(geometry);
2991 ymax := st_ymax(geometry);
2992 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2994 -- if the geometry completely covers the box don't bother to slice any more
2995 IF ST_AREA(secbox) = area THEN
2996 RETURN NEXT geometry;
3000 xmid := (xmin+xmax)/2;
3001 ymid := (ymin+ymax)/2;
3004 FOR seg IN 1..4 LOOP
3007 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
3010 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
3013 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3016 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3019 IF st_intersects(geometry, secbox) THEN
3020 secgeo := st_intersection(geometry, secbox);
3021 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3022 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3023 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3025 RETURN NEXT geo.geom;
3037 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3038 RETURNS SETOF GEOMETRY
3043 -- 10000000000 is ~~ 1x1 degree
3044 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3045 RETURN NEXT geo.geom;
3053 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3057 osmtype character(1);
3061 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3062 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3063 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3064 -- force delete from place/placex by making it a very small geometry
3065 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;
3066 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3073 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3081 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
3082 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3083 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3084 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3085 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3086 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3087 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));
3088 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3089 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));
3095 ELSEIF rank < 18 THEN
3097 ELSEIF rank < 20 THEN
3099 ELSEIF rank = 21 THEN
3101 ELSEIF rank < 24 THEN
3103 ELSEIF rank < 26 THEN
3104 diameter := 0.002; -- 100 to 200 meters
3105 ELSEIF rank < 28 THEN
3106 diameter := 0.001; -- 50 to 100 meters
3108 IF diameter > 0 THEN
3110 -- roads may cause reparenting for >27 rank places
3111 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3112 ELSEIF rank >= 16 THEN
3113 -- up to rank 16, street-less addresses may need reparenting
3114 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);
3116 -- for all other places the search terms may change as well
3117 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);