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 street, addr_place from placex
770 where osm_type = 'N' and osm_id = ANY(nodes)
771 and (street is not null or 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 RETURN parent_place_id;
813 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT,
814 parent_place_id BIGINT, partition INTEGER,
815 country_code TEXT, geometry_sector INTEGER,
816 defpostalcode TEXT, geom GEOMETRY) RETURNS INTEGER
828 orginalstartnumber INTEGER;
829 originalnumberrange INTEGER;
836 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
838 ELSEIF interpolationtype = 'all' THEN
840 ELSEIF interpolationtype ~ '^\d+$' THEN
841 stepsize := interpolationtype::INTEGER;
846 select nodes from planet_osm_ways where id = wayid INTO waynodes;
848 IF array_upper(waynodes, 1) IS NULL THEN
856 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
858 -- If there is a place of a type other than place/house, use that because
859 -- it is guaranteed to be the original node. For place/house types use the
860 -- one with the smallest id because the original node was created first.
861 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
862 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
863 and indexed_status < 100
864 order by (type = 'house'),place_id limit 1 INTO nextnode;
865 IF nextnode.place_id IS NOT NULL THEN
867 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
868 -- Make sure that the point is actually on the line. That might
869 -- be a bit paranoid but ensures that the algorithm still works
870 -- should osm2pgsql attempt to repair geometries.
871 splitline := split_line_on_node(linegeo, nextnode.geometry);
872 sectiongeo := ST_GeometryN(splitline, 1);
873 linegeo := ST_GeometryN(splitline, 2);
875 sectiongeo = linegeo;
877 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
879 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
880 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
881 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
883 IF (startnumber > endnumber) THEN
884 housenum := endnumber;
885 endnumber := startnumber;
886 startnumber := housenum;
887 sectiongeo := ST_Reverse(sectiongeo);
889 orginalstartnumber := startnumber;
890 originalnumberrange := endnumber - startnumber;
892 startnumber := startnumber + stepsize;
893 -- correct for odd/even
894 IF (interpolationtype = 'odd' AND startnumber%2 = 0)
895 OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
896 startnumber := startnumber - 1;
898 endnumber := endnumber - 1;
900 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id
901 and place_id != prevnode.place_id;
902 FOR housenum IN startnumber..endnumber BY stepsize LOOP
903 insert into placex (place_id, partition, osm_type, osm_id,
904 class, type, admin_level, housenumber,
906 country_code, parent_place_id, rank_address, rank_search,
907 indexed_status, indexed_date, geometry_sector,
909 values (nextval('seq_place'), partition, 'N', prevnode.osm_id,
910 'place', 'address', prevnode.admin_level, housenum,
911 coalesce(prevnode.postcode, defpostalcode),
912 prevnode.country_code, parent_place_id, 30, 30,
913 0, now(), geometry_sector, calculated_country_code,
914 ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
915 newpoints := newpoints + 1;
916 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
920 -- early break if we are out of line string,
921 -- might happen when a line string loops back on itself
922 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
926 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
927 prevnode := nextnode;
931 --RAISE WARNING 'interpolation points % ',newpoints;
938 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
944 country_code VARCHAR(2);
945 default_language VARCHAR(10);
949 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
951 -- ignore interpolated addresses
952 IF NEW.class = 'place' and NEW.type = 'address' THEN
957 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
958 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
962 IF ST_IsEmpty(NEW.geometry) OR NOT ST_IsValid(NEW.geometry) OR ST_X(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEW.geometry))::text in ('NaN','Infinity','-Infinity') THEN
963 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
964 RAISE WARNING 'invalid geometry %',NEW.osm_id;
968 IF NEW.osm_type = 'R' THEN
969 -- invalid multipolygons can crash postgis, don't even bother to try!
972 NEW.geometry := ST_buffer(NEW.geometry,0);
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 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
979 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
981 NEW.place_id := nextval('seq_place');
982 NEW.indexed_status := 1; --STATUS_NEW
984 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
986 NEW.partition := get_partition(NEW.calculated_country_code);
987 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
989 -- copy 'name' to or from the default language (if there is a default language)
990 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
991 default_language := get_country_language_code(NEW.calculated_country_code);
992 IF default_language IS NOT NULL THEN
993 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
994 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
995 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
996 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1001 IF NEW.admin_level > 15 THEN
1002 NEW.admin_level := 15;
1005 IF NEW.housenumber IS NOT NULL THEN
1006 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1009 IF NEW.osm_type = 'X' THEN
1010 -- E'X'ternal records should already be in the right format so do nothing
1012 NEW.rank_search := 30;
1013 NEW.rank_address := NEW.rank_search;
1015 -- By doing in postgres we have the country available to us - currently only used for postcode
1016 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
1018 IF NEW.postcode IS NULL THEN
1019 -- most likely just a part of a multipolygon postcode boundary, throw it away
1023 NEW.name := hstore('ref', NEW.postcode);
1025 IF NEW.calculated_country_code = 'gb' THEN
1027 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
1028 NEW.rank_search := 25;
1029 NEW.rank_address := 5;
1030 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
1031 NEW.rank_search := 23;
1032 NEW.rank_address := 5;
1033 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
1034 NEW.rank_search := 21;
1035 NEW.rank_address := 5;
1038 ELSEIF NEW.calculated_country_code = 'sg' THEN
1040 IF NEW.postcode ~ '^([0-9]{6})$' THEN
1041 NEW.rank_search := 25;
1042 NEW.rank_address := 11;
1045 ELSEIF NEW.calculated_country_code = 'de' THEN
1047 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1048 NEW.rank_search := 21;
1049 NEW.rank_address := 11;
1053 -- Guess at the postcode format and coverage (!)
1054 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1055 NEW.rank_search := 21;
1056 NEW.rank_address := 11;
1058 -- Does it look splitable into and area and local code?
1059 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1061 IF postcode IS NOT NULL THEN
1062 NEW.rank_search := 25;
1063 NEW.rank_address := 11;
1064 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1065 NEW.rank_search := 21;
1066 NEW.rank_address := 11;
1071 ELSEIF NEW.class = 'place' THEN
1072 IF NEW.type in ('continent') THEN
1073 NEW.rank_search := 2;
1074 NEW.rank_address := NEW.rank_search;
1075 NEW.calculated_country_code := NULL;
1076 ELSEIF NEW.type in ('sea') THEN
1077 NEW.rank_search := 2;
1078 NEW.rank_address := 0;
1079 NEW.calculated_country_code := NULL;
1080 ELSEIF NEW.type in ('country') THEN
1081 NEW.rank_search := 4;
1082 NEW.rank_address := NEW.rank_search;
1083 ELSEIF NEW.type in ('state') THEN
1084 NEW.rank_search := 8;
1085 NEW.rank_address := NEW.rank_search;
1086 ELSEIF NEW.type in ('region') THEN
1087 NEW.rank_search := 18; -- dropped from previous value of 10
1088 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1089 ELSEIF NEW.type in ('county') THEN
1090 NEW.rank_search := 12;
1091 NEW.rank_address := NEW.rank_search;
1092 ELSEIF NEW.type in ('city') THEN
1093 NEW.rank_search := 16;
1094 NEW.rank_address := NEW.rank_search;
1095 ELSEIF NEW.type in ('island') THEN
1096 NEW.rank_search := 17;
1097 NEW.rank_address := 0;
1098 ELSEIF NEW.type in ('town') THEN
1099 NEW.rank_search := 18;
1100 NEW.rank_address := 16;
1101 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1102 NEW.rank_search := 19;
1103 NEW.rank_address := 16;
1104 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1105 NEW.rank_search := 20;
1106 NEW.rank_address := NEW.rank_search;
1107 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1108 NEW.rank_search := 20;
1109 NEW.rank_address := 0;
1110 -- Irish townlands, tagged as place=locality and locality=townland
1111 IF (NEW.extratags -> 'locality') = 'townland' THEN
1112 NEW.rank_address := 20;
1114 ELSEIF NEW.type in ('neighbourhood') THEN
1115 NEW.rank_search := 22;
1116 NEW.rank_address := 22;
1117 ELSEIF NEW.type in ('house','building') THEN
1118 NEW.rank_search := 30;
1119 NEW.rank_address := NEW.rank_search;
1120 ELSEIF NEW.type in ('houses') THEN
1121 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1122 NEW.rank_search := 28;
1123 NEW.rank_address := 0;
1126 ELSEIF NEW.class = 'boundary' THEN
1127 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1128 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1131 NEW.rank_search := NEW.admin_level * 2;
1132 IF NEW.type = 'administrative' THEN
1133 NEW.rank_address := NEW.rank_search;
1135 NEW.rank_address := 0;
1137 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1138 NEW.rank_search := 22;
1139 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1140 NEW.rank_address := NEW.rank_search;
1142 NEW.rank_address := 0;
1144 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1145 NEW.rank_search := 18;
1146 NEW.rank_address := 0;
1147 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1148 NEW.rank_search := 4;
1149 NEW.rank_address := NEW.rank_search;
1150 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1152 -- any feature more than 5 square miles is probably worth indexing
1153 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1154 NEW.rank_search := 22;
1155 NEW.rank_address := 0;
1156 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1157 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1158 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1160 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1162 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1164 ELSEIF NEW.class = 'waterway' THEN
1165 IF NEW.osm_type = 'R' THEN
1166 NEW.rank_search := 16;
1168 NEW.rank_search := 17;
1170 NEW.rank_address := 0;
1171 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
1172 NEW.rank_search := 27;
1173 NEW.rank_address := NEW.rank_search;
1174 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1175 NEW.rank_search := 26;
1176 NEW.rank_address := NEW.rank_search;
1177 ELSEIF NEW.class = 'mountain_pass' THEN
1178 NEW.rank_search := 20;
1179 NEW.rank_address := 0;
1184 IF NEW.rank_search > 30 THEN
1185 NEW.rank_search := 30;
1188 IF NEW.rank_address > 30 THEN
1189 NEW.rank_address := 30;
1192 IF (NEW.extratags -> 'capital') = 'yes' THEN
1193 NEW.rank_search := NEW.rank_search - 1;
1196 -- a country code make no sense below rank 4 (country)
1197 IF NEW.rank_search < 4 THEN
1198 NEW.calculated_country_code := NULL;
1201 -- Block import below rank 22
1202 -- IF NEW.rank_search > 22 THEN
1206 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1208 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1210 IF NEW.rank_address > 0 THEN
1211 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1212 -- Performance: We just can't handle re-indexing for country level changes
1213 IF st_area(NEW.geometry) < 1 THEN
1214 -- mark items within the geometry for re-indexing
1215 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1217 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1218 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1219 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));
1220 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1221 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));
1224 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1226 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1227 IF NEW.type='postcode' THEN
1229 ELSEIF NEW.rank_search < 16 THEN
1231 ELSEIF NEW.rank_search < 18 THEN
1233 ELSEIF NEW.rank_search < 20 THEN
1235 ELSEIF NEW.rank_search = 21 THEN
1237 ELSEIF NEW.rank_search < 24 THEN
1239 ELSEIF NEW.rank_search < 26 THEN
1240 diameter := 0.002; -- 100 to 200 meters
1241 ELSEIF NEW.rank_search < 28 THEN
1242 diameter := 0.001; -- 50 to 100 meters
1244 IF diameter > 0 THEN
1245 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1246 IF NEW.rank_search >= 26 THEN
1247 -- roads may cause reparenting for >27 rank places
1248 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1249 ELSEIF NEW.rank_search >= 16 THEN
1250 -- up to rank 16, street-less addresses may need reparenting
1251 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);
1253 -- for all other places the search terms may change as well
1254 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);
1260 -- add to tables for special search
1261 -- Note: won't work on initial import because the classtype tables
1262 -- do not yet exist. It won't hurt either.
1263 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1264 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1266 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1267 USING NEW.place_id, ST_Centroid(NEW.geometry);
1271 -- IF NEW.rank_search < 26 THEN
1272 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1281 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1286 place_centroid GEOMETRY;
1288 search_maxdistance FLOAT[];
1289 search_mindistance FLOAT[];
1290 address_havelevel BOOLEAN[];
1297 relation_members TEXT[];
1299 linkedplacex RECORD;
1300 search_diameter FLOAT;
1301 search_prevdiameter FLOAT;
1302 search_maxrank INTEGER;
1303 address_maxrank INTEGER;
1304 address_street_word_id INTEGER;
1305 address_street_word_ids INTEGER[];
1306 parent_place_id_rank BIGINT;
1311 location_rank_search INTEGER;
1312 location_distance FLOAT;
1313 location_parent GEOMETRY;
1314 location_isaddress BOOLEAN;
1315 location_keywords INTEGER[];
1319 default_language TEXT;
1320 name_vector INTEGER[];
1321 nameaddress_vector INTEGER[];
1323 linked_node_id BIGINT;
1329 IF OLD.indexed_status = 100 THEN
1330 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1331 delete from placex where place_id = OLD.place_id;
1335 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1339 -- ignore interpolated addresses
1340 IF NEW.class = 'place' and NEW.type = 'address' THEN
1344 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1346 --RAISE WARNING '%',NEW.place_id;
1347 --RAISE WARNING '%', NEW;
1349 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1350 -- Silently do nothing
1354 -- TODO: this test is now redundant?
1355 IF OLD.indexed_status != 0 THEN
1357 NEW.indexed_date = now();
1359 result := deleteSearchName(NEW.partition, NEW.place_id);
1360 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1361 result := deleteRoad(NEW.partition, NEW.place_id);
1362 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1363 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1365 IF NEW.linked_place_id is not null THEN
1369 -- Speed up searches - just use the centroid of the feature
1370 -- cheaper but less acurate
1371 place_centroid := ST_PointOnSurface(NEW.geometry);
1372 NEW.centroid := null;
1374 -- recalculate country and partition
1375 IF NEW.rank_search = 4 THEN
1376 -- for countries, believe the mapped country code,
1377 -- so that we remain in the right partition if the boundaries
1379 NEW.partition := get_partition(lower(NEW.country_code));
1380 IF NEW.partition = 0 THEN
1381 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1382 NEW.partition := get_partition(NEW.calculated_country_code);
1384 NEW.calculated_country_code := lower(NEW.country_code);
1387 IF NEW.rank_search > 4 THEN
1388 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1389 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1391 NEW.calculated_country_code := NULL;
1393 NEW.partition := get_partition(NEW.calculated_country_code);
1395 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1397 -- interpolations XXXXX
1398 IF NEW.class = 'place' AND NEW.type = 'houses'THEN
1399 IF osm_type = 'W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1400 NEW.parent_place_id := get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1401 NEW.partition, place_centroid, NEW.geometry);
1402 IF NEW.parent_place_id is not null THEN
1403 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1409 -- waterway ways are linked when they are part of a relation and have the same class/type
1410 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1411 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1413 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1414 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1415 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1416 FOR linked_node_id IN SELECT place_id FROM placex
1417 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1418 and class = NEW.class and type = NEW.type
1419 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1421 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1428 -- Adding ourselves to the list simplifies address calculations later
1429 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1431 -- What level are we searching from
1432 search_maxrank := NEW.rank_search;
1434 -- Thought this wasn't needed but when we add new languages to the country_name table
1435 -- we need to update the existing names
1436 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1437 default_language := get_country_language_code(NEW.calculated_country_code);
1438 IF default_language IS NOT NULL THEN
1439 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1440 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1441 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1442 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1447 -- Initialise the name vector using our name
1448 name_vector := make_keywords(NEW.name);
1449 nameaddress_vector := '{}'::int[];
1451 -- some tag combinations add a special id for search
1452 tagpairid := get_tagpair(NEW.class,NEW.type);
1453 IF tagpairid IS NOT NULL THEN
1454 name_vector := name_vector + tagpairid;
1458 address_havelevel[i] := false;
1461 NEW.importance := null;
1462 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1463 IF NEW.importance IS NULL THEN
1464 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;
1467 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1469 -- For low level elements we inherit from our parent road
1470 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1472 --RAISE WARNING 'finding street for %', NEW;
1474 -- We won't get a better centroid, besides these places are too small to care
1475 NEW.centroid := place_centroid;
1477 NEW.parent_place_id := null;
1479 -- to do that we have to find our parent road
1480 -- Copy data from linked items (points on ways, addr:street links, relations)
1481 -- Note that addr:street links can only be indexed once the street itself is indexed
1482 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1484 -- if there is no address information, see if we can get it from a surrounding building
1485 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1486 FOR location IN select * from placex where ST_Covers(geometry, place_centroid) and rank_search > 28 and (housenumber is not null or street is not null or addr_place is not null) AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1488 NEW.housenumber := location.housenumber;
1489 NEW.street := location.street;
1490 NEW.addr_place := location.addr_place;
1494 -- Is this node part of a relation?
1495 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1497 -- At the moment we only process one type of relation - associatedStreet
1498 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1499 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1500 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1501 --RAISE WARNING 'node in relation %',relation;
1502 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1503 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1509 --RAISE WARNING 'x1';
1510 -- Is this node part of a way?
1511 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1512 --RAISE WARNING '%', way;
1513 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1515 --RAISE WARNING '%', location;
1516 -- Way IS a road then we are on it - that must be our road
1517 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1518 --RAISE WARNING 'node in way that is a street %',location;
1519 NEW.parent_place_id := location.place_id;
1522 -- Is the WAY part of a relation
1523 IF NEW.parent_place_id IS NULL THEN
1524 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1526 -- At the moment we only process one type of relation - associatedStreet
1527 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1528 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1529 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1530 --RAISE WARNING 'node in way that is in a relation %',relation;
1531 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1532 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1539 -- If the way contains an explicit name of a street copy it
1540 -- Slightly less strict then above because data is copied from any object.
1541 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1542 --RAISE WARNING 'node in way that has a streetname %',location;
1543 NEW.street := location.street;
1544 NEW.addr_place := location.addr_place;
1547 -- If this way is a street interpolation line then it is probably as good as we are going to get
1548 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND NEW.addr_place IS NULL AND location.class = 'place' and location.type='houses' THEN
1549 -- Try and find a way that is close roughly parellel to this line
1550 FOR relation IN SELECT place_id FROM placex
1551 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1552 and st_geometrytype(location.geometry) in ('ST_LineString')
1553 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1554 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1555 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1557 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1558 NEW.parent_place_id := relation.place_id;
1567 --RAISE WARNING 'x2';
1569 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1570 -- Is this way part of a relation?
1571 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1573 -- At the moment we only process one type of relation - associatedStreet
1574 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1575 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1576 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1577 --RAISE WARNING 'way that is in a relation %',relation;
1578 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1579 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1586 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1588 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1589 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1590 IF address_street_word_ids IS NOT NULL THEN
1591 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1592 NEW.parent_place_id := location.place_id;
1597 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1598 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1599 IF address_street_word_ids IS NOT NULL THEN
1600 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1601 NEW.parent_place_id := location.place_id;
1606 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1607 -- Still nothing, just use the nearest road
1608 IF NEW.parent_place_id IS NULL THEN
1609 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1610 NEW.parent_place_id := location.place_id;
1615 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1617 -- If we didn't find any road fallback to standard method
1618 IF NEW.parent_place_id IS NOT NULL THEN
1620 -- Add the street to the address as zero distance to force to front of list
1621 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1622 address_havelevel[26] := true;
1624 -- Import address details from parent, reclculating distance in process
1625 -- 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
1626 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1627 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1629 -- Get the details of the parent road
1630 select * from search_name where place_id = NEW.parent_place_id INTO location;
1631 NEW.calculated_country_code := location.country_code;
1633 --RAISE WARNING '%', NEW.name;
1634 -- If there is no name it isn't searchable, don't bother to create a search record
1635 IF NEW.name is NULL THEN
1639 -- Merge address from parent
1640 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1641 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1643 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1644 -- Just be happy with inheriting from parent road only
1646 IF NEW.rank_search <= 25 THEN
1647 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1650 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);
1657 -- RAISE WARNING ' INDEXING Started:';
1658 -- RAISE WARNING ' INDEXING: %',NEW;
1660 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1662 -- see if we have any special relation members
1663 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1665 -- RAISE WARNING 'get_osm_rel_members, label';
1666 IF relation_members IS NOT NULL THEN
1667 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1669 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1670 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1672 -- If we don't already have one use this as the centre point of the geometry
1673 IF NEW.centroid IS NULL THEN
1674 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1677 -- merge in the label name, re-init word vector
1678 IF NOT linkedPlacex.name IS NULL THEN
1679 NEW.name := linkedPlacex.name || NEW.name;
1680 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1683 -- merge in extra tags
1684 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1686 -- mark the linked place (excludes from search results)
1687 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1689 -- keep a note of the node id in case we need it for wikipedia in a bit
1690 linked_node_id := linkedPlacex.osm_id;
1695 IF NEW.centroid IS NULL THEN
1697 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1699 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1700 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1702 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1703 -- But that can be fixed by explicitly setting the label in the data
1704 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1705 AND NEW.rank_address = linkedPlacex.rank_address THEN
1707 -- If we don't already have one use this as the centre point of the geometry
1708 IF NEW.centroid IS NULL THEN
1709 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1712 -- merge in the name, re-init word vector
1713 IF NOT linkedPlacex.name IS NULL THEN
1714 NEW.name := linkedPlacex.name || NEW.name;
1715 name_vector := make_keywords(NEW.name);
1718 -- merge in extra tags
1719 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1721 -- mark the linked place (excludes from search results)
1722 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1724 -- keep a note of the node id in case we need it for wikipedia in a bit
1725 linked_node_id := linkedPlacex.osm_id;
1737 -- Name searches can be done for ways as well as relations
1738 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1740 -- not found one yet? how about doing a name search
1741 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1743 FOR linkedPlacex IN select placex.* from placex WHERE
1744 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1745 AND placex.rank_address = NEW.rank_address
1746 AND placex.place_id != NEW.place_id
1747 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1748 AND st_covers(NEW.geometry, placex.geometry)
1751 -- If we don't already have one use this as the centre point of the geometry
1752 IF NEW.centroid IS NULL THEN
1753 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1756 -- merge in the name, re-init word vector
1757 NEW.name := linkedPlacex.name || NEW.name;
1758 name_vector := make_keywords(NEW.name);
1760 -- merge in extra tags
1761 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1763 -- mark the linked place (excludes from search results)
1764 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1766 -- keep a note of the node id in case we need it for wikipedia in a bit
1767 linked_node_id := linkedPlacex.osm_id;
1771 IF NEW.centroid IS NOT NULL THEN
1772 place_centroid := NEW.centroid;
1773 -- Place might have had only a name tag before but has now received translations
1774 -- from the linked place. Make sure a name tag for the default language exists in
1776 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1777 default_language := get_country_language_code(NEW.calculated_country_code);
1778 IF default_language IS NOT NULL THEN
1779 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1780 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1781 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1782 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1788 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1789 IF NEW.importance is null THEN
1790 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1792 -- Still null? how about looking it up by the node id
1793 IF NEW.importance IS NULL THEN
1794 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;
1799 -- make sure all names are in the word table
1800 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1801 perform create_country(NEW.name, lower(NEW.country_code));
1804 NEW.parent_place_id = 0;
1805 parent_place_id_rank = 0;
1807 -- convert isin to array of tokenids
1808 isin_tokens := '{}'::int[];
1809 IF NEW.isin IS NOT NULL THEN
1810 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1811 IF array_upper(isin, 1) IS NOT NULL THEN
1812 FOR i IN 1..array_upper(isin, 1) LOOP
1813 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1814 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1815 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1816 isin_tokens := isin_tokens || address_street_word_id;
1819 -- merge word into address vector
1820 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1821 IF address_street_word_id IS NOT NULL THEN
1822 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1827 IF NEW.postcode IS NOT NULL THEN
1828 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1829 IF array_upper(isin, 1) IS NOT NULL THEN
1830 FOR i IN 1..array_upper(isin, 1) LOOP
1831 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1832 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1833 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1834 isin_tokens := isin_tokens || address_street_word_id;
1837 -- merge into address vector
1838 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1839 IF address_street_word_id IS NOT NULL THEN
1840 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1846 -- for the USA we have an additional address table. Merge in zip codes from there too
1847 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1848 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1849 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1850 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1851 isin_tokens := isin_tokens || address_street_word_id;
1853 -- also merge in the single word version
1854 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1855 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1859 -- RAISE WARNING 'ISIN: %', isin_tokens;
1861 -- Process area matches
1862 location_rank_search := 0;
1863 location_distance := 0;
1864 location_parent := NULL;
1865 -- added ourself as address already
1866 address_havelevel[NEW.rank_address] := true;
1867 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1868 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1870 --RAISE WARNING ' AREA: %',location;
1872 IF location.rank_address != location_rank_search THEN
1873 location_rank_search := location.rank_address;
1874 IF location.isguess THEN
1875 location_distance := location.distance * 1.5;
1877 IF location.rank_address <= 12 THEN
1878 -- for county and above, if we have an area consider that exact
1879 -- (It would be nice to relax the constraint for places close to
1880 -- the boundary but we'd need the exact geometry for that. Too
1882 location_distance = 0;
1884 -- Below county level remain slightly fuzzy.
1885 location_distance := location.distance * 0.5;
1889 CONTINUE WHEN location.keywords <@ location_keywords;
1892 IF location.distance < location_distance OR NOT location.isguess THEN
1893 location_keywords := location.keywords;
1895 location_isaddress := NOT address_havelevel[location.rank_address];
1896 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1897 location_isaddress := ST_Contains(location_parent,location.centroid);
1900 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1901 -- Add it to the list of search terms
1902 IF location.rank_search > 4 THEN
1903 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1905 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1907 IF location_isaddress THEN
1909 address_havelevel[location.rank_address] := true;
1910 IF NOT location.isguess THEN
1911 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1914 IF location.rank_address > parent_place_id_rank THEN
1915 NEW.parent_place_id = location.place_id;
1916 parent_place_id_rank = location.rank_address;
1921 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1927 -- try using the isin value to find parent places
1928 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1929 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1930 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1931 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1933 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1935 --RAISE WARNING ' ISIN: %',location;
1937 IF location.rank_search > 4 THEN
1938 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1939 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1940 address_havelevel[location.rank_address] := true;
1942 IF location.rank_address > parent_place_id_rank THEN
1943 NEW.parent_place_id = location.place_id;
1944 parent_place_id_rank = location.rank_address;
1954 -- for long ways we should add search terms for the entire length
1955 IF st_length(NEW.geometry) > 0.05 THEN
1957 location_rank_search := 0;
1958 location_distance := 0;
1960 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1962 IF location.rank_address != location_rank_search THEN
1963 location_rank_search := location.rank_address;
1964 location_distance := location.distance * 1.5;
1967 IF location.rank_search > 4 AND location.distance < location_distance THEN
1969 -- Add it to the list of search terms
1970 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1971 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1979 -- if we have a name add this to the name search table
1980 IF NEW.name IS NOT NULL THEN
1982 IF NEW.rank_search <= 25 THEN
1983 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1986 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1987 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1990 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);
1994 -- If we've not managed to pick up a better one - default centroid
1995 IF NEW.centroid IS NULL THEN
1996 NEW.centroid := place_centroid;
2006 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
2012 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
2014 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
2015 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
2016 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
2017 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
2019 IF OLD.rank_address < 30 THEN
2021 -- mark everything linked to this place for re-indexing
2022 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
2023 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
2024 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
2026 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
2027 DELETE FROM place_addressline where address_place_id = OLD.place_id;
2029 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
2030 b := deleteRoad(OLD.partition, OLD.place_id);
2032 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
2033 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
2034 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
2038 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2040 IF OLD.rank_address < 26 THEN
2041 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2044 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2046 IF OLD.name is not null THEN
2047 b := deleteSearchName(OLD.partition, OLD.place_id);
2050 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2052 DELETE FROM place_addressline where place_id = OLD.place_id;
2054 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2056 -- remove from tables for special search
2057 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2058 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2060 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2063 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2071 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2077 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2079 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2080 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2081 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;
2083 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2089 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;
2097 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2102 existingplacex RECORD;
2103 existinggeometry GEOMETRY;
2104 existingplace_id BIGINT;
2109 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2110 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2112 IF FALSE and NEW.osm_type = 'R' THEN
2113 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;
2114 --DEBUG: RAISE WARNING '%', existingplacex;
2117 -- Just block these - lots and pointless
2118 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2119 -- if the name tag was removed, older versions might still be lurking in the place table
2120 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2124 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
2125 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2126 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2127 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2131 -- Patch in additional country names
2132 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2133 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2136 -- Have we already done this place?
2137 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;
2139 -- Get the existing place_id
2140 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;
2142 -- Handle a place changing type by removing the old data
2143 -- My generated 'place' types are causing havok because they overlap with real keys
2144 -- TODO: move them to their own special purpose key/class to avoid collisions
2145 IF existing.osm_type IS NULL THEN
2146 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2149 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2150 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2153 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2154 AND st_area(existing.geometry) > 0.02
2155 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2156 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2158 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2159 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2163 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2164 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2166 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2167 IF existingplacex.osm_type IS NULL OR
2168 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2171 IF existingplacex.osm_type IS NOT NULL THEN
2172 -- sanity check: ignore admin_level changes on places with too many active children
2173 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2174 --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;
2175 --LIMIT INDEXING: IF i > 100000 THEN
2176 --LIMIT INDEXING: RETURN null;
2177 --LIMIT INDEXING: END IF;
2180 IF existing.osm_type IS NOT NULL THEN
2181 -- pathological case caused by the triggerless copy into place during initial import
2182 -- force delete even for large areas, it will be reinserted later
2183 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;
2184 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2187 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2188 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2189 street, addr_place, isin, postcode, country_code, extratags, geometry)
2190 values (NEW.osm_type
2206 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2211 -- Various ways to do the update
2213 -- Debug, what's changed?
2215 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2216 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2218 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2219 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2221 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2222 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2224 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2225 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2227 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2228 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2230 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2231 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2233 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2234 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2238 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2239 IF existing.geometry::text != NEW.geometry::text
2240 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2241 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2244 -- Get the version of the geometry actually used (in placex table)
2245 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;
2247 -- Performance limit
2248 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2250 -- 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
2251 update placex set indexed_status = 2 where indexed_status = 0 and
2252 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2253 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2254 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2256 update placex set indexed_status = 2 where indexed_status = 0 and
2257 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2258 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2259 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2265 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2266 IF FALSE AND existingplacex.rank_search < 26
2267 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2268 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2269 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2270 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2271 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2272 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2273 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2276 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2278 IF st_area(NEW.geometry) < 0.5 THEN
2279 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2280 and placex.place_id = place_addressline.place_id and indexed_status = 0
2281 and (rank_search < 28 or name is not null);
2288 -- Anything else has changed - reindex the lot
2289 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2290 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2291 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2292 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2293 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2294 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2295 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2297 -- performance, can't take the load of re-indexing a whole country / huge area
2298 IF st_area(NEW.geometry) < 0.5 THEN
2299 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2300 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2307 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2308 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2309 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2310 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2311 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2312 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2313 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2314 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2315 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2316 OR existing.geometry::text != NEW.geometry::text
2321 housenumber = NEW.housenumber,
2322 street = NEW.street,
2323 addr_place = NEW.addr_place,
2325 postcode = NEW.postcode,
2326 country_code = NEW.country_code,
2327 extratags = NEW.extratags,
2328 admin_level = NEW.admin_level,
2329 geometry = NEW.geometry
2330 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2332 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2333 IF NEW.postcode IS NULL THEN
2334 -- postcode was deleted, no longer retain in placex
2335 DELETE FROM placex where place_id = existingplacex.place_id;
2339 NEW.name := hstore('ref', NEW.postcode);
2344 housenumber = NEW.housenumber,
2345 street = NEW.street,
2346 addr_place = NEW.addr_place,
2348 postcode = NEW.postcode,
2349 country_code = NEW.country_code,
2350 parent_place_id = null,
2351 extratags = NEW.extratags,
2352 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2354 geometry = NEW.geometry
2355 where place_id = existingplacex.place_id;
2359 -- Abort the add (we modified the existing place instead)
2363 $$ LANGUAGE plpgsql;
2365 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2372 IF name is null THEN
2376 search := languagepref;
2378 FOR j IN 1..array_upper(search, 1) LOOP
2379 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2380 return trim(name->search[j]);
2384 -- anything will do as a fallback - just take the first name type thing there is
2385 search := avals(name);
2389 LANGUAGE plpgsql IMMUTABLE;
2392 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2403 search := ARRAY['ref'];
2406 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2409 select rank_address,name,distance,length(name::text) as namelength
2410 from place_addressline join placex on (address_place_id = placex.place_id)
2411 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2412 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2414 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2415 FOR j IN 1..array_upper(search, 1) LOOP
2416 FOR k IN 1..array_upper(location.name, 1) LOOP
2417 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
2418 result[(100 - location.rank_address)] := trim(location.name[k].value);
2419 found := location.rank_address;
2426 RETURN array_to_string(result,', ');
2431 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2443 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2444 currresult := trim(get_name_by_language(location.name, languagepref));
2445 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2446 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2447 prevresult := currresult;
2451 RETURN array_to_string(result,', ');
2456 DROP TYPE IF EXISTS addressline CASCADE;
2457 create type addressline as (
2464 admin_level INTEGER,
2467 rank_address INTEGER,
2471 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2474 for_place_id BIGINT;
2479 countrylocation RECORD;
2480 searchcountrycode varchar(2);
2481 searchhousenumber TEXT;
2482 searchhousename HSTORE;
2483 searchrankaddress INTEGER;
2484 searchpostcode TEXT;
2491 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2492 WHERE place_id = in_place_id
2493 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2495 IF for_place_id IS NULL THEN
2496 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2497 WHERE place_id = in_place_id
2498 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2501 IF for_place_id IS NULL THEN
2502 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2503 WHERE place_id = in_place_id and rank_address = 30
2504 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2507 IF for_place_id IS NULL THEN
2508 for_place_id := in_place_id;
2509 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2510 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2513 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2516 hadcountry := false;
2518 select placex.place_id, osm_type, osm_id,
2519 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2520 class, type, admin_level, true as fromarea, true as isaddress,
2521 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2522 0 as distance, calculated_country_code, postcode
2524 where place_id = for_place_id
2526 --RAISE WARNING '%',location;
2527 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2528 searchcountrycode := location.calculated_country_code;
2530 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2531 location.isaddress := FALSE;
2533 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2534 searchpostcode := location.postcode;
2536 IF location.rank_address = 4 AND location.isaddress THEN
2539 IF location.rank_address < 4 AND NOT hadcountry THEN
2540 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2541 IF countryname IS NOT NULL THEN
2542 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2543 RETURN NEXT countrylocation;
2546 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2547 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2548 location.distance)::addressline;
2549 RETURN NEXT countrylocation;
2550 found := location.rank_address;
2554 select placex.place_id, osm_type, osm_id,
2555 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2556 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2557 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2558 admin_level, fromarea, isaddress,
2559 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,
2560 distance,calculated_country_code,postcode
2561 from place_addressline join placex on (address_place_id = placex.place_id)
2562 where place_addressline.place_id = for_place_id
2563 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2564 and address_place_id != for_place_id
2565 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2566 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2568 --RAISE WARNING '%',location;
2569 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2570 searchcountrycode := location.calculated_country_code;
2572 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2573 location.isaddress := FALSE;
2575 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2576 searchpostcode := location.postcode;
2578 IF location.rank_address = 4 AND location.isaddress THEN
2581 IF location.rank_address < 4 AND NOT hadcountry THEN
2582 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2583 IF countryname IS NOT NULL THEN
2584 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2585 RETURN NEXT countrylocation;
2588 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2589 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2590 location.distance)::addressline;
2591 RETURN NEXT countrylocation;
2592 found := location.rank_address;
2596 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2597 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2598 IF countryname IS NOT NULL THEN
2599 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2600 RETURN NEXT location;
2604 IF searchcountrycode IS NOT NULL THEN
2605 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2606 RETURN NEXT location;
2609 IF searchhousename IS NOT NULL THEN
2610 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2611 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2612 RETURN NEXT location;
2615 IF searchhousenumber IS NOT NULL THEN
2616 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2617 RETURN NEXT location;
2620 IF searchpostcode IS NOT NULL THEN
2621 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2622 RETURN NEXT location;
2631 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2634 numfeatures integer;
2638 housenumber = place.housenumber,
2639 street = place.street,
2640 addr_place = place.addr_place,
2642 postcode = place.postcode,
2643 country_code = place.country_code,
2644 parent_place_id = null
2646 where placex.place_id = search_place_id
2647 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2648 and place.class = placex.class and place.type = placex.type;
2649 update placex set indexed_status = 2 where place_id = search_place_id;
2650 update placex set indexed_status = 0 where place_id = search_place_id;
2656 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2662 ELSEIF rank < 4 THEN
2664 ELSEIF rank < 8 THEN
2666 ELSEIF rank < 12 THEN
2668 ELSEIF rank < 16 THEN
2670 ELSEIF rank = 16 THEN
2672 ELSEIF rank = 17 THEN
2673 RETURN 'Town / Island';
2674 ELSEIF rank = 18 THEN
2675 RETURN 'Village / Hamlet';
2676 ELSEIF rank = 20 THEN
2678 ELSEIF rank = 21 THEN
2679 RETURN 'Postcode Area';
2680 ELSEIF rank = 22 THEN
2681 RETURN 'Croft / Farm / Locality / Islet';
2682 ELSEIF rank = 23 THEN
2683 RETURN 'Postcode Area';
2684 ELSEIF rank = 25 THEN
2685 RETURN 'Postcode Point';
2686 ELSEIF rank = 26 THEN
2687 RETURN 'Street / Major Landmark';
2688 ELSEIF rank = 27 THEN
2689 RETURN 'Minory Street / Path';
2690 ELSEIF rank = 28 THEN
2691 RETURN 'House / Building';
2693 RETURN 'Other: '||rank;
2700 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2706 ELSEIF rank < 2 THEN
2708 ELSEIF rank < 4 THEN
2710 ELSEIF rank = 5 THEN
2712 ELSEIF rank < 8 THEN
2714 ELSEIF rank < 12 THEN
2716 ELSEIF rank < 16 THEN
2718 ELSEIF rank = 16 THEN
2720 ELSEIF rank = 17 THEN
2721 RETURN 'Town / Village / Hamlet';
2722 ELSEIF rank = 20 THEN
2724 ELSEIF rank = 21 THEN
2725 RETURN 'Postcode Area';
2726 ELSEIF rank = 22 THEN
2727 RETURN 'Croft / Farm / Locality / Islet';
2728 ELSEIF rank = 23 THEN
2729 RETURN 'Postcode Area';
2730 ELSEIF rank = 25 THEN
2731 RETURN 'Postcode Point';
2732 ELSEIF rank = 26 THEN
2733 RETURN 'Street / Major Landmark';
2734 ELSEIF rank = 27 THEN
2735 RETURN 'Minory Street / Path';
2736 ELSEIF rank = 28 THEN
2737 RETURN 'House / Building';
2739 RETURN 'Other: '||rank;
2746 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2753 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2754 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2761 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2769 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2771 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2772 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2774 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2782 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2783 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2788 place_centroid GEOMETRY;
2789 out_partition INTEGER;
2790 out_parent_place_id BIGINT;
2792 address_street_word_id INTEGER;
2797 place_centroid := ST_Centroid(pointgeo);
2798 out_partition := get_partition(in_countrycode);
2799 out_parent_place_id := null;
2801 address_street_word_id := get_name_id(make_standard_name(in_street));
2802 IF address_street_word_id IS NOT NULL THEN
2803 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2804 out_parent_place_id := location.place_id;
2808 IF out_parent_place_id IS NULL THEN
2809 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2810 out_parent_place_id := location.place_id;
2814 out_postcode := in_postcode;
2815 IF out_postcode IS NULL THEN
2816 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2818 IF out_postcode IS NULL THEN
2819 out_postcode := getNearestPostcode(out_partition, place_centroid);
2823 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2824 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2825 newpoints := newpoints + 1;
2832 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2839 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2840 IF members[i+1] = member THEN
2841 result := result || members[i];
2850 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2856 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2857 IF members[i+1] = ANY(memberLabels) THEN
2858 RETURN NEXT members[i];
2867 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2868 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2870 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2871 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
2872 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2873 ), '') AS bytea), 'UTF8');
2875 LANGUAGE SQL IMMUTABLE STRICT;
2877 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2881 RETURN decode_url_part(p);
2883 WHEN others THEN return null;
2886 LANGUAGE plpgsql IMMUTABLE;
2888 DROP TYPE wikipedia_article_match CASCADE;
2889 create type wikipedia_article_match as (
2895 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2901 wiki_article_title TEXT;
2902 wiki_article_language TEXT;
2903 result wikipedia_article_match;
2905 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'];
2907 WHILE langs[i] IS NOT NULL LOOP
2908 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2909 IF wiki_article is not null THEN
2910 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2911 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2912 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2913 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2914 wiki_article := replace(wiki_article,' ','_');
2915 IF strpos(wiki_article, ':') IN (3,4) THEN
2916 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2917 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2919 wiki_article_title := trim(wiki_article);
2920 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;
2923 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2924 from wikipedia_article
2925 where language = wiki_article_language and
2926 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2928 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2929 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2930 where wikipedia_redirect.language = wiki_article_language and
2931 (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'\\',''))
2932 order by importance desc limit 1 INTO result;
2934 IF result.language is not null THEN
2945 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2946 RETURNS SETOF GEOMETRY
2960 remainingdepth INTEGER;
2965 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2967 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2968 RETURN NEXT geometry;
2972 remainingdepth := maxdepth - 1;
2973 area := ST_AREA(geometry);
2974 IF remainingdepth < 1 OR area < maxarea THEN
2975 RETURN NEXT geometry;
2979 xmin := st_xmin(geometry);
2980 xmax := st_xmax(geometry);
2981 ymin := st_ymin(geometry);
2982 ymax := st_ymax(geometry);
2983 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2985 -- if the geometry completely covers the box don't bother to slice any more
2986 IF ST_AREA(secbox) = area THEN
2987 RETURN NEXT geometry;
2991 xmid := (xmin+xmax)/2;
2992 ymid := (ymin+ymax)/2;
2995 FOR seg IN 1..4 LOOP
2998 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
3001 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
3004 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
3007 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
3010 IF st_intersects(geometry, secbox) THEN
3011 secgeo := st_intersection(geometry, secbox);
3012 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
3013 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
3014 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
3016 RETURN NEXT geo.geom;
3028 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
3029 RETURNS SETOF GEOMETRY
3034 -- 10000000000 is ~~ 1x1 degree
3035 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
3036 RETURN NEXT geo.geom;
3044 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3048 osmtype character(1);
3052 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3053 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3054 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3055 -- force delete from place/placex by making it a very small geometry
3056 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;
3057 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3064 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3072 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
3073 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3074 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3075 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3076 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3077 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3078 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));
3079 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3080 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));
3086 ELSEIF rank < 18 THEN
3088 ELSEIF rank < 20 THEN
3090 ELSEIF rank = 21 THEN
3092 ELSEIF rank < 24 THEN
3094 ELSEIF rank < 26 THEN
3095 diameter := 0.002; -- 100 to 200 meters
3096 ELSEIF rank < 28 THEN
3097 diameter := 0.001; -- 50 to 100 meters
3099 IF diameter > 0 THEN
3101 -- roads may cause reparenting for >27 rank places
3102 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3103 ELSEIF rank >= 16 THEN
3104 -- up to rank 16, street-less addresses may need reparenting
3105 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);
3107 -- for all other places the search terms may change as well
3108 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);