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_word_score(wordscores wordscore[], words text[]) RETURNS integer
484 IF (wordscores is null OR words is null) THEN
489 FOR idxword in 1 .. array_upper(words, 1) LOOP
490 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
491 IF wordscores[idxscores].word = words[idxword] THEN
492 result := result + wordscores[idxscores].score;
500 LANGUAGE plpgsql IMMUTABLE;
502 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
505 place_centre GEOMETRY;
508 place_centre := ST_PointOnSurface(place);
510 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
512 -- Try for a OSM polygon
513 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
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
520 -- Try for OSM fallback data
521 -- The order is to deal with places like HongKong that are 'states' within another polygon
522 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
524 RETURN nearcountry.country_code;
527 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
529 -- Natural earth data
530 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
532 RETURN nearcountry.country_code;
535 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
538 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
540 RETURN nearcountry.country_code;
543 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
545 -- Natural earth data
546 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
548 RETURN nearcountry.country_code;
554 LANGUAGE plpgsql IMMUTABLE;
556 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
561 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
563 RETURN lower(nearcountry.country_default_language_code);
568 LANGUAGE plpgsql IMMUTABLE;
570 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
575 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
577 RETURN lower(nearcountry.country_default_language_codes);
582 LANGUAGE plpgsql IMMUTABLE;
584 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
589 FOR nearcountry IN select partition from country_name where country_code = in_country_code
591 RETURN nearcountry.partition;
596 LANGUAGE plpgsql IMMUTABLE;
598 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
602 DELETE FROM location_area where place_id = OLD_place_id;
603 -- TODO:location_area
609 CREATE OR REPLACE FUNCTION add_location(
611 country_code varchar(2),
615 rank_address INTEGER,
630 IF rank_search > 25 THEN
631 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
634 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
636 x := deleteLocationArea(partition, place_id, rank_search);
639 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
642 centroid := ST_Centroid(geometry);
644 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
645 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
648 ELSEIF rank_search < 26 THEN
651 IF rank_address = 0 THEN
653 ELSEIF rank_search <= 14 THEN
655 ELSEIF rank_search <= 15 THEN
657 ELSEIF rank_search <= 16 THEN
659 ELSEIF rank_search <= 17 THEN
661 ELSEIF rank_search <= 21 THEN
663 ELSEIF rank_search = 25 THEN
667 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
669 secgeo := ST_Buffer(geometry, diameter);
670 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
675 secgeo := ST_Buffer(geometry, 0.0002);
676 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
679 secgeo := ST_Buffer(geometry, 0.001);
680 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
689 CREATE OR REPLACE FUNCTION update_location(
692 place_country_code varchar(2),
695 rank_address INTEGER,
703 b := deleteLocationArea(partition, place_id, rank_search);
704 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
705 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
710 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
721 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
722 FOR childplace IN select * from search_name,place_addressline
723 where address_place_id = parent_place_id
724 and search_name.place_id = place_addressline.place_id
726 delete from search_name where place_id = childplace.place_id;
727 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
728 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
730 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
731 childplace.name_vector := childplace.name_vector || to_add;
733 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
734 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
735 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
743 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
746 newkeywords INTEGER[];
747 addedkeywords INTEGER[];
748 removedkeywords INTEGER[];
752 newkeywords := make_keywords(name);
753 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
754 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
755 where place_id = OLD_place_id into addedkeywords, removedkeywords;
757 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
759 IF #removedkeywords > 0 THEN
760 -- abort due to tokens removed
764 IF #addedkeywords > 0 THEN
765 -- short circuit - no changes
769 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
770 RETURN search_name_add_words(OLD_place_id, addedkeywords);
776 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
788 orginalstartnumber INTEGER;
789 originalnumberrange INTEGER;
794 search_place_id BIGINT;
798 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
800 ELSEIF interpolationtype = 'all' THEN
802 ELSEIF interpolationtype ~ '^\d+$' THEN
803 stepsize := interpolationtype::INTEGER;
808 select nodes from planet_osm_ways where id = wayid INTO waynodes;
810 IF array_upper(waynodes, 1) IS NULL THEN
814 select postcode, geometry from placex where osm_type = 'W' and osm_id = wayid
815 INTO defpostalcode, linegeo;
817 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
824 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
826 -- If there is a place of a type other than place/house, use that because
827 -- it is guaranteed to be the original node. For place/house types use the
828 -- one with the smallest id because the original node was created first.
829 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
830 select place_id from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and indexed_status < 100 order by (type = 'house'),place_id limit 1 INTO search_place_id;
831 IF search_place_id IS NOT NULL THEN
832 select * from placex where place_id = search_place_id INTO nextnode;
834 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
835 -- Make sure that the point is actually on the line. That might
836 -- be a bit paranoid but ensures that the algorithm still works
837 -- should osm2pgsql attempt to repair geometries.
838 splitline := split_line_on_node(linegeo, nextnode.geometry);
839 sectiongeo := ST_GeometryN(splitline, 1);
840 linegeo := ST_GeometryN(splitline, 2);
842 sectiongeo = linegeo;
844 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
846 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
847 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
848 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
850 IF (startnumber > endnumber) THEN
851 housenum := endnumber;
852 endnumber := startnumber;
853 startnumber := housenum;
854 sectiongeo := ST_Reverse(sectiongeo);
856 orginalstartnumber := startnumber;
857 originalnumberrange := endnumber - startnumber;
859 startnumber := startnumber + stepsize;
860 -- correct for odd/even
861 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
862 startnumber := startnumber - 1;
864 endnumber := endnumber - 1;
866 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
867 FOR housenum IN startnumber..endnumber BY stepsize LOOP
868 -- this should really copy postcodes but it puts a huge burden on
869 -- the system for no big benefit ideally postcodes should move up to the way
870 insert into placex (osm_type, osm_id, class, type, admin_level,
871 housenumber, street, addr_place, isin, postcode,
872 country_code, parent_place_id, rank_address, rank_search,
873 indexed_status, geometry)
874 values ('N', prevnode.osm_id, 'place', 'house', prevnode.admin_level,
875 housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
876 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search,
877 1, ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
878 newpoints := newpoints + 1;
879 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
883 -- early break if we are out of line string,
884 -- might happen when a line string loops back on itself
885 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
889 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
890 prevnode := nextnode;
894 --RAISE WARNING 'interpolation points % ',newpoints;
901 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
907 country_code VARCHAR(2);
908 default_language VARCHAR(10);
912 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
915 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
916 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
920 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
921 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
922 RAISE WARNING 'invalid geometry %',NEW.osm_id;
926 IF NEW.osm_type = 'R' THEN
927 -- invalid multipolygons can crash postgis, don't even bother to try!
930 NEW.geometry := ST_buffer(NEW.geometry,0);
931 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
932 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
937 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
939 NEW.place_id := nextval('seq_place');
940 NEW.indexed_status := 1; --STATUS_NEW
942 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
944 NEW.partition := get_partition(NEW.calculated_country_code);
945 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
947 -- copy 'name' to or from the default language (if there is a default language)
948 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
949 default_language := get_country_language_code(NEW.calculated_country_code);
950 IF default_language IS NOT NULL THEN
951 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
952 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
953 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
954 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
959 IF NEW.admin_level > 15 THEN
960 NEW.admin_level := 15;
963 IF NEW.housenumber IS NOT NULL THEN
964 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
967 IF NEW.osm_type = 'X' THEN
968 -- E'X'ternal records should already be in the right format so do nothing
970 NEW.rank_search := 30;
971 NEW.rank_address := NEW.rank_search;
973 -- By doing in postgres we have the country available to us - currently only used for postcode
974 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
976 IF NEW.postcode IS NULL THEN
977 -- most likely just a part of a multipolygon postcode boundary, throw it away
981 NEW.name := hstore('ref', NEW.postcode);
983 IF NEW.calculated_country_code = 'gb' THEN
985 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
986 NEW.rank_search := 25;
987 NEW.rank_address := 5;
988 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
989 NEW.rank_search := 23;
990 NEW.rank_address := 5;
991 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
992 NEW.rank_search := 21;
993 NEW.rank_address := 5;
996 ELSEIF NEW.calculated_country_code = 'sg' THEN
998 IF NEW.postcode ~ '^([0-9]{6})$' THEN
999 NEW.rank_search := 25;
1000 NEW.rank_address := 11;
1003 ELSEIF NEW.calculated_country_code = 'de' THEN
1005 IF NEW.postcode ~ '^([0-9]{5})$' THEN
1006 NEW.rank_search := 21;
1007 NEW.rank_address := 11;
1011 -- Guess at the postcode format and coverage (!)
1012 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
1013 NEW.rank_search := 21;
1014 NEW.rank_address := 11;
1016 -- Does it look splitable into and area and local code?
1017 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
1019 IF postcode IS NOT NULL THEN
1020 NEW.rank_search := 25;
1021 NEW.rank_address := 11;
1022 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1023 NEW.rank_search := 21;
1024 NEW.rank_address := 11;
1029 ELSEIF NEW.class = 'place' THEN
1030 IF NEW.type in ('continent') THEN
1031 NEW.rank_search := 2;
1032 NEW.rank_address := NEW.rank_search;
1033 NEW.calculated_country_code := NULL;
1034 ELSEIF NEW.type in ('sea') THEN
1035 NEW.rank_search := 2;
1036 NEW.rank_address := 0;
1037 NEW.calculated_country_code := NULL;
1038 ELSEIF NEW.type in ('country') THEN
1039 NEW.rank_search := 4;
1040 NEW.rank_address := NEW.rank_search;
1041 ELSEIF NEW.type in ('state') THEN
1042 NEW.rank_search := 8;
1043 NEW.rank_address := NEW.rank_search;
1044 ELSEIF NEW.type in ('region') THEN
1045 NEW.rank_search := 18; -- dropped from previous value of 10
1046 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1047 ELSEIF NEW.type in ('county') THEN
1048 NEW.rank_search := 12;
1049 NEW.rank_address := NEW.rank_search;
1050 ELSEIF NEW.type in ('city') THEN
1051 NEW.rank_search := 16;
1052 NEW.rank_address := NEW.rank_search;
1053 ELSEIF NEW.type in ('island') THEN
1054 NEW.rank_search := 17;
1055 NEW.rank_address := 0;
1056 ELSEIF NEW.type in ('town') THEN
1057 NEW.rank_search := 18;
1058 NEW.rank_address := 16;
1059 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1060 NEW.rank_search := 19;
1061 NEW.rank_address := 16;
1062 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1063 NEW.rank_search := 20;
1064 NEW.rank_address := NEW.rank_search;
1065 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1066 NEW.rank_search := 20;
1067 NEW.rank_address := 0;
1068 -- Irish townlands, tagged as place=locality and locality=townland
1069 IF (NEW.extratags -> 'locality') = 'townland' THEN
1070 NEW.rank_address := 20;
1072 ELSEIF NEW.type in ('neighbourhood') THEN
1073 NEW.rank_search := 22;
1074 NEW.rank_address := 22;
1075 ELSEIF NEW.type in ('house','building') THEN
1076 NEW.rank_search := 30;
1077 NEW.rank_address := NEW.rank_search;
1078 ELSEIF NEW.type in ('houses') THEN
1079 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1080 -- insert new point into place for each derived building
1081 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1082 NEW.rank_search := 28;
1083 NEW.rank_address := 0;
1086 ELSEIF NEW.class = 'boundary' THEN
1087 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1088 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1091 NEW.rank_search := NEW.admin_level * 2;
1092 IF NEW.type = 'administrative' THEN
1093 NEW.rank_address := NEW.rank_search;
1095 NEW.rank_address := 0;
1097 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1098 NEW.rank_search := 22;
1099 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1100 NEW.rank_address := NEW.rank_search;
1102 NEW.rank_address := 0;
1104 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1105 NEW.rank_search := 18;
1106 NEW.rank_address := 0;
1107 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1108 NEW.rank_search := 4;
1109 NEW.rank_address := NEW.rank_search;
1110 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1112 -- any feature more than 5 square miles is probably worth indexing
1113 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1114 NEW.rank_search := 22;
1115 NEW.rank_address := 0;
1116 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1117 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1118 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1120 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1122 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1124 ELSEIF NEW.class = 'waterway' THEN
1125 IF NEW.osm_type = 'R' THEN
1126 NEW.rank_search := 16;
1128 NEW.rank_search := 17;
1130 NEW.rank_address := 0;
1131 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
1132 NEW.rank_search := 27;
1133 NEW.rank_address := NEW.rank_search;
1134 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1135 NEW.rank_search := 26;
1136 NEW.rank_address := NEW.rank_search;
1137 ELSEIF NEW.class = 'mountain_pass' THEN
1138 NEW.rank_search := 20;
1139 NEW.rank_address := 0;
1144 IF NEW.rank_search > 30 THEN
1145 NEW.rank_search := 30;
1148 IF NEW.rank_address > 30 THEN
1149 NEW.rank_address := 30;
1152 IF (NEW.extratags -> 'capital') = 'yes' THEN
1153 NEW.rank_search := NEW.rank_search - 1;
1156 -- a country code make no sense below rank 4 (country)
1157 IF NEW.rank_search < 4 THEN
1158 NEW.calculated_country_code := NULL;
1161 -- Block import below rank 22
1162 -- IF NEW.rank_search > 22 THEN
1166 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1168 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1170 IF NEW.rank_address > 0 THEN
1171 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1172 -- Performance: We just can't handle re-indexing for country level changes
1173 IF st_area(NEW.geometry) < 1 THEN
1174 -- mark items within the geometry for re-indexing
1175 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1177 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1178 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1179 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));
1180 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1181 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));
1184 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1186 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1187 IF NEW.type='postcode' THEN
1189 ELSEIF NEW.rank_search < 16 THEN
1191 ELSEIF NEW.rank_search < 18 THEN
1193 ELSEIF NEW.rank_search < 20 THEN
1195 ELSEIF NEW.rank_search = 21 THEN
1197 ELSEIF NEW.rank_search < 24 THEN
1199 ELSEIF NEW.rank_search < 26 THEN
1200 diameter := 0.002; -- 100 to 200 meters
1201 ELSEIF NEW.rank_search < 28 THEN
1202 diameter := 0.001; -- 50 to 100 meters
1204 IF diameter > 0 THEN
1205 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1206 IF NEW.rank_search >= 26 THEN
1207 -- roads may cause reparenting for >27 rank places
1208 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1209 ELSEIF NEW.rank_search >= 16 THEN
1210 -- up to rank 16, street-less addresses may need reparenting
1211 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);
1213 -- for all other places the search terms may change as well
1214 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);
1220 -- add to tables for special search
1221 -- Note: won't work on initial import because the classtype tables
1222 -- do not yet exist. It won't hurt either.
1223 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1224 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1226 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1227 USING NEW.place_id, ST_Centroid(NEW.geometry);
1231 -- IF NEW.rank_search < 26 THEN
1232 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1241 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1246 place_centroid GEOMETRY;
1248 search_maxdistance FLOAT[];
1249 search_mindistance FLOAT[];
1250 address_havelevel BOOLEAN[];
1251 -- search_scores wordscore[];
1252 -- search_scores_pos INTEGER;
1259 relation_members TEXT[];
1261 linkedplacex RECORD;
1262 search_diameter FLOAT;
1263 search_prevdiameter FLOAT;
1264 search_maxrank INTEGER;
1265 address_maxrank INTEGER;
1266 address_street_word_id INTEGER;
1267 address_street_word_ids INTEGER[];
1268 parent_place_id_rank BIGINT;
1273 location_rank_search INTEGER;
1274 location_distance FLOAT;
1275 location_parent GEOMETRY;
1276 location_isaddress BOOLEAN;
1280 default_language TEXT;
1281 name_vector INTEGER[];
1282 nameaddress_vector INTEGER[];
1284 linked_node_id BIGINT;
1290 IF OLD.indexed_status = 100 THEN
1291 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1292 delete from placex where place_id = OLD.place_id;
1296 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1300 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1302 --RAISE WARNING '%',NEW.place_id;
1303 --RAISE WARNING '%', NEW;
1305 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1306 -- Silently do nothing
1310 -- TODO: this test is now redundant?
1311 IF OLD.indexed_status != 0 THEN
1313 NEW.indexed_date = now();
1315 result := deleteSearchName(NEW.partition, NEW.place_id);
1316 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1317 result := deleteRoad(NEW.partition, NEW.place_id);
1318 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1319 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1321 IF NEW.linked_place_id is not null THEN
1325 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1326 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1330 -- Speed up searches - just use the centroid of the feature
1331 -- cheaper but less acurate
1332 place_centroid := ST_PointOnSurface(NEW.geometry);
1333 NEW.centroid := null;
1335 -- recalculate country and partition
1336 IF NEW.rank_search = 4 THEN
1337 -- for countries, believe the mapped country code,
1338 -- so that we remain in the right partition if the boundaries
1340 NEW.partition := get_partition(lower(NEW.country_code));
1341 IF NEW.partition = 0 THEN
1342 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1343 NEW.partition := get_partition(NEW.calculated_country_code);
1345 NEW.calculated_country_code := lower(NEW.country_code);
1348 IF NEW.rank_search > 4 THEN
1349 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1350 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1352 NEW.calculated_country_code := NULL;
1354 NEW.partition := get_partition(NEW.calculated_country_code);
1356 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1358 -- waterway ways are linked when they are part of a relation and have the same class/type
1359 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1360 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1362 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1363 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1364 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1365 FOR linked_node_id IN SELECT place_id FROM placex
1366 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1367 and class = NEW.class and type = NEW.type
1368 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1370 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1377 -- Adding ourselves to the list simplifies address calculations later
1378 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1380 -- What level are we searching from
1381 search_maxrank := NEW.rank_search;
1383 -- Thought this wasn't needed but when we add new languages to the country_name table
1384 -- we need to update the existing names
1385 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1386 default_language := get_country_language_code(NEW.calculated_country_code);
1387 IF default_language IS NOT NULL THEN
1388 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1389 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1390 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1391 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1396 -- Initialise the name vector using our name
1397 name_vector := make_keywords(NEW.name);
1398 nameaddress_vector := '{}'::int[];
1400 -- some tag combinations add a special id for search
1401 tagpairid := get_tagpair(NEW.class,NEW.type);
1402 IF tagpairid IS NOT NULL THEN
1403 name_vector := name_vector + tagpairid;
1407 address_havelevel[i] := false;
1410 NEW.importance := null;
1411 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1412 IF NEW.importance IS NULL THEN
1413 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;
1416 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1418 -- For low level elements we inherit from our parent road
1419 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1421 --RAISE WARNING 'finding street for %', NEW;
1423 -- We won't get a better centroid, besides these places are too small to care
1424 NEW.centroid := place_centroid;
1426 NEW.parent_place_id := null;
1428 -- to do that we have to find our parent road
1429 -- Copy data from linked items (points on ways, addr:street links, relations)
1430 -- Note that addr:street links can only be indexed once the street itself is indexed
1431 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1433 -- if there is no address information, see if we can get it from a surrounding building
1434 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1435 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')
1437 NEW.housenumber := location.housenumber;
1438 NEW.street := location.street;
1439 NEW.addr_place := location.addr_place;
1443 -- Is this node part of a relation?
1444 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1446 -- At the moment we only process one type of relation - associatedStreet
1447 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1448 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1449 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1450 --RAISE WARNING 'node in relation %',relation;
1451 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1452 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1458 --RAISE WARNING 'x1';
1459 -- Is this node part of a way?
1460 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1461 --RAISE WARNING '%', way;
1462 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1464 --RAISE WARNING '%', location;
1465 -- Way IS a road then we are on it - that must be our road
1466 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1467 --RAISE WARNING 'node in way that is a street %',location;
1468 NEW.parent_place_id := location.place_id;
1471 -- Is the WAY part of a relation
1472 IF NEW.parent_place_id IS NULL THEN
1473 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1475 -- At the moment we only process one type of relation - associatedStreet
1476 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1477 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1478 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1479 --RAISE WARNING 'node in way that is in a relation %',relation;
1480 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1481 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1488 -- If the way contains an explicit name of a street copy it
1489 -- Slightly less strict then above because data is copied from any object.
1490 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1491 --RAISE WARNING 'node in way that has a streetname %',location;
1492 NEW.street := location.street;
1493 NEW.addr_place := location.addr_place;
1496 -- If this way is a street interpolation line then it is probably as good as we are going to get
1497 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
1498 -- Try and find a way that is close roughly parellel to this line
1499 FOR relation IN SELECT place_id FROM placex
1500 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1501 and st_geometrytype(location.geometry) in ('ST_LineString')
1502 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1503 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1504 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1506 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1507 NEW.parent_place_id := relation.place_id;
1516 --RAISE WARNING 'x2';
1518 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1519 -- Is this way part of a relation?
1520 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1522 -- At the moment we only process one type of relation - associatedStreet
1523 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1524 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1525 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1526 --RAISE WARNING 'way that is in a relation %',relation;
1527 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1528 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1535 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1537 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1538 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1539 IF address_street_word_ids IS NOT NULL THEN
1540 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1541 NEW.parent_place_id := location.place_id;
1546 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1547 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1548 IF address_street_word_ids IS NOT NULL THEN
1549 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1550 NEW.parent_place_id := location.place_id;
1555 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1556 -- Still nothing, just use the nearest road
1557 IF NEW.parent_place_id IS NULL THEN
1558 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1559 NEW.parent_place_id := location.place_id;
1564 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1566 -- If we didn't find any road fallback to standard method
1567 IF NEW.parent_place_id IS NOT NULL THEN
1569 -- Add the street to the address as zero distance to force to front of list
1570 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1571 address_havelevel[26] := true;
1573 -- Import address details from parent, reclculating distance in process
1574 -- 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
1575 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1576 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1578 -- Get the details of the parent road
1579 select * from search_name where place_id = NEW.parent_place_id INTO location;
1580 NEW.calculated_country_code := location.country_code;
1582 --RAISE WARNING '%', NEW.name;
1583 -- If there is no name it isn't searchable, don't bother to create a search record
1584 IF NEW.name is NULL THEN
1588 -- Merge address from parent
1589 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1590 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1592 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1593 -- Just be happy with inheriting from parent road only
1595 IF NEW.rank_search <= 25 THEN
1596 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1599 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);
1606 -- RAISE WARNING ' INDEXING Started:';
1607 -- RAISE WARNING ' INDEXING: %',NEW;
1609 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1611 -- see if we have any special relation members
1612 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1614 -- RAISE WARNING 'get_osm_rel_members, label';
1615 IF relation_members IS NOT NULL THEN
1616 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1618 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1619 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1621 -- If we don't already have one use this as the centre point of the geometry
1622 IF NEW.centroid IS NULL THEN
1623 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1626 -- merge in the label name, re-init word vector
1627 IF NOT linkedPlacex.name IS NULL THEN
1628 NEW.name := linkedPlacex.name || NEW.name;
1629 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1632 -- merge in extra tags
1633 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1635 -- mark the linked place (excludes from search results)
1636 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1638 -- keep a note of the node id in case we need it for wikipedia in a bit
1639 linked_node_id := linkedPlacex.osm_id;
1644 IF NEW.centroid IS NULL THEN
1646 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1648 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1649 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1651 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1652 -- But that can be fixed by explicitly setting the label in the data
1653 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1654 AND NEW.rank_address = linkedPlacex.rank_address THEN
1656 -- If we don't already have one use this as the centre point of the geometry
1657 IF NEW.centroid IS NULL THEN
1658 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1661 -- merge in the name, re-init word vector
1662 IF NOT linkedPlacex.name IS NULL THEN
1663 NEW.name := linkedPlacex.name || NEW.name;
1664 name_vector := make_keywords(NEW.name);
1667 -- merge in extra tags
1668 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1670 -- mark the linked place (excludes from search results)
1671 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1673 -- keep a note of the node id in case we need it for wikipedia in a bit
1674 linked_node_id := linkedPlacex.osm_id;
1686 -- Name searches can be done for ways as well as relations
1687 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1689 -- not found one yet? how about doing a name search
1690 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1692 FOR linkedPlacex IN select placex.* from placex WHERE
1693 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1694 AND placex.rank_address = NEW.rank_address
1695 AND placex.place_id != NEW.place_id
1696 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1697 AND st_covers(NEW.geometry, placex.geometry)
1700 -- If we don't already have one use this as the centre point of the geometry
1701 IF NEW.centroid IS NULL THEN
1702 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1705 -- merge in the name, re-init word vector
1706 NEW.name := linkedPlacex.name || NEW.name;
1707 name_vector := make_keywords(NEW.name);
1709 -- merge in extra tags
1710 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1712 -- mark the linked place (excludes from search results)
1713 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1715 -- keep a note of the node id in case we need it for wikipedia in a bit
1716 linked_node_id := linkedPlacex.osm_id;
1720 IF NEW.centroid IS NOT NULL THEN
1721 place_centroid := NEW.centroid;
1722 -- Place might have had only a name tag before but has now received translations
1723 -- from the linked place. Make sure a name tag for the default language exists in
1725 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1726 default_language := get_country_language_code(NEW.calculated_country_code);
1727 IF default_language IS NOT NULL THEN
1728 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1729 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1730 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1731 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1737 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1738 IF NEW.importance is null THEN
1739 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1741 -- Still null? how about looking it up by the node id
1742 IF NEW.importance IS NULL THEN
1743 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;
1748 -- make sure all names are in the word table
1749 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1750 perform create_country(NEW.name, lower(NEW.country_code));
1753 NEW.parent_place_id = 0;
1754 parent_place_id_rank = 0;
1756 -- convert isin to array of tokenids
1757 isin_tokens := '{}'::int[];
1758 IF NEW.isin IS NOT NULL THEN
1759 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1760 IF array_upper(isin, 1) IS NOT NULL THEN
1761 FOR i IN 1..array_upper(isin, 1) LOOP
1762 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1763 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1764 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1765 isin_tokens := isin_tokens || address_street_word_id;
1768 -- merge word into address vector
1769 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1770 IF address_street_word_id IS NOT NULL THEN
1771 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1776 IF NEW.postcode IS NOT NULL THEN
1777 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1778 IF array_upper(isin, 1) IS NOT NULL THEN
1779 FOR i IN 1..array_upper(isin, 1) LOOP
1780 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1781 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1782 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1783 isin_tokens := isin_tokens || address_street_word_id;
1786 -- merge into address vector
1787 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1788 IF address_street_word_id IS NOT NULL THEN
1789 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1795 -- for the USA we have an additional address table. Merge in zip codes from there too
1796 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1797 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1798 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1799 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1800 isin_tokens := isin_tokens || address_street_word_id;
1802 -- also merge in the single word version
1803 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1804 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1808 -- RAISE WARNING 'ISIN: %', isin_tokens;
1810 -- Process area matches
1811 location_rank_search := 0;
1812 location_distance := 0;
1813 location_parent := NULL;
1814 -- added ourself as address already
1815 address_havelevel[NEW.rank_address] := true;
1816 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1817 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1819 --RAISE WARNING ' AREA: %',location;
1821 IF location.rank_address != location_rank_search THEN
1822 location_rank_search := location.rank_address;
1823 location_distance := location.distance * 1.5;
1826 IF location.distance < location_distance OR NOT location.isguess THEN
1828 location_isaddress := NOT address_havelevel[location.rank_address];
1829 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1830 location_isaddress := ST_Contains(location_parent,location.centroid);
1833 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1834 -- Add it to the list of search terms
1835 IF location.rank_search > 4 THEN
1836 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1838 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1840 IF location_isaddress THEN
1842 address_havelevel[location.rank_address] := true;
1843 IF NOT location.isguess THEN
1844 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1847 IF location.rank_address > parent_place_id_rank THEN
1848 NEW.parent_place_id = location.place_id;
1849 parent_place_id_rank = location.rank_address;
1854 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1860 -- try using the isin value to find parent places
1861 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1862 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1863 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1864 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1866 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1868 --RAISE WARNING ' ISIN: %',location;
1870 IF location.rank_search > 4 THEN
1871 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1872 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1873 address_havelevel[location.rank_address] := true;
1875 IF location.rank_address > parent_place_id_rank THEN
1876 NEW.parent_place_id = location.place_id;
1877 parent_place_id_rank = location.rank_address;
1887 -- for long ways we should add search terms for the entire length
1888 IF st_length(NEW.geometry) > 0.05 THEN
1890 location_rank_search := 0;
1891 location_distance := 0;
1893 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1895 IF location.rank_address != location_rank_search THEN
1896 location_rank_search := location.rank_address;
1897 location_distance := location.distance * 1.5;
1900 IF location.rank_search > 4 AND location.distance < location_distance THEN
1902 -- Add it to the list of search terms
1903 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1904 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1912 -- if we have a name add this to the name search table
1913 IF NEW.name IS NOT NULL THEN
1915 IF NEW.rank_search <= 25 THEN
1916 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1919 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1920 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1923 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);
1927 -- If we've not managed to pick up a better one - default centroid
1928 IF NEW.centroid IS NULL THEN
1929 NEW.centroid := place_centroid;
1939 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1945 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1947 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1948 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1949 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1950 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1952 IF OLD.rank_address < 30 THEN
1954 -- mark everything linked to this place for re-indexing
1955 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1956 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1957 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1959 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1960 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1962 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1963 b := deleteRoad(OLD.partition, OLD.place_id);
1965 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1966 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1967 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1971 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1973 IF OLD.rank_address < 26 THEN
1974 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1977 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1979 IF OLD.name is not null THEN
1980 b := deleteSearchName(OLD.partition, OLD.place_id);
1983 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1985 DELETE FROM place_addressline where place_id = OLD.place_id;
1987 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1989 -- remove from tables for special search
1990 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1991 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1993 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1996 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2004 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2010 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2012 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2013 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2014 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;
2016 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2022 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;
2030 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2035 existingplacex RECORD;
2036 existinggeometry GEOMETRY;
2037 existingplace_id BIGINT;
2042 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2043 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2045 IF FALSE and NEW.osm_type = 'R' THEN
2046 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;
2047 --DEBUG: RAISE WARNING '%', existingplacex;
2050 -- Just block these - lots and pointless
2051 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2052 -- if the name tag was removed, older versions might still be lurking in the place table
2053 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2057 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
2058 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2059 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2060 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2064 -- Patch in additional country names
2065 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2066 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2069 -- Have we already done this place?
2070 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;
2072 -- Get the existing place_id
2073 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;
2075 -- Handle a place changing type by removing the old data
2076 -- My generated 'place' types are causing havok because they overlap with real keys
2077 -- TODO: move them to their own special purpose key/class to avoid collisions
2078 IF existing.osm_type IS NULL THEN
2079 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2082 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2083 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2086 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2087 AND st_area(existing.geometry) > 0.02
2088 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2089 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2091 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2092 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2096 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2097 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2099 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2100 IF existingplacex.osm_type IS NULL OR
2101 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2104 IF existingplacex.osm_type IS NOT NULL THEN
2105 -- sanity check: ignore admin_level changes on places with too many active children
2106 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2107 --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;
2108 --LIMIT INDEXING: IF i > 100000 THEN
2109 --LIMIT INDEXING: RETURN null;
2110 --LIMIT INDEXING: END IF;
2113 IF existing.osm_type IS NOT NULL THEN
2114 -- pathological case caused by the triggerless copy into place during initial import
2115 -- force delete even for large areas, it will be reinserted later
2116 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;
2117 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2120 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2121 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2122 street, addr_place, isin, postcode, country_code, extratags, geometry)
2123 values (NEW.osm_type
2139 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2144 -- Various ways to do the update
2146 -- Debug, what's changed?
2148 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2149 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2151 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2152 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2154 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2155 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2157 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2158 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2160 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2161 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2163 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2164 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2166 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2167 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2171 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2172 IF existing.geometry::text != NEW.geometry::text
2173 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2174 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2177 -- Get the version of the geometry actually used (in placex table)
2178 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;
2180 -- Performance limit
2181 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2183 -- 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
2184 update placex set indexed_status = 2 where indexed_status = 0 and
2185 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2186 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2187 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2189 update placex set indexed_status = 2 where indexed_status = 0 and
2190 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2191 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2192 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2198 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2199 IF FALSE AND existingplacex.rank_search < 26
2200 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2201 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2202 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2203 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2204 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2205 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2206 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2209 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2211 IF st_area(NEW.geometry) < 0.5 THEN
2212 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2213 and placex.place_id = place_addressline.place_id and indexed_status = 0
2214 and (rank_search < 28 or name is not null);
2221 -- Anything else has changed - reindex the lot
2222 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2223 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2224 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2225 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2226 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2227 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2228 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2230 -- performance, can't take the load of re-indexing a whole country / huge area
2231 IF st_area(NEW.geometry) < 0.5 THEN
2232 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2233 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2240 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2241 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2242 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2243 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2244 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2245 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2246 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2247 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2248 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2249 OR existing.geometry::text != NEW.geometry::text
2254 housenumber = NEW.housenumber,
2255 street = NEW.street,
2256 addr_place = NEW.addr_place,
2258 postcode = NEW.postcode,
2259 country_code = NEW.country_code,
2260 extratags = NEW.extratags,
2261 admin_level = NEW.admin_level,
2262 geometry = NEW.geometry
2263 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2265 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2266 IF NEW.postcode IS NULL THEN
2267 -- postcode was deleted, no longer retain in placex
2268 DELETE FROM placex where place_id = existingplacex.place_id;
2272 NEW.name := hstore('ref', NEW.postcode);
2277 housenumber = NEW.housenumber,
2278 street = NEW.street,
2279 addr_place = NEW.addr_place,
2281 postcode = NEW.postcode,
2282 country_code = NEW.country_code,
2283 parent_place_id = null,
2284 extratags = NEW.extratags,
2285 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2287 geometry = NEW.geometry
2288 where place_id = existingplacex.place_id;
2292 -- Abort the add (we modified the existing place instead)
2296 $$ LANGUAGE plpgsql;
2298 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2305 IF name is null THEN
2309 search := languagepref;
2311 FOR j IN 1..array_upper(search, 1) LOOP
2312 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2313 return trim(name->search[j]);
2317 -- anything will do as a fallback - just take the first name type thing there is
2318 search := avals(name);
2322 LANGUAGE plpgsql IMMUTABLE;
2324 --CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2327 -- searchnodes INTEGER[];
2332 -- searchnodes := '{}';
2333 -- FOR j IN 1..array_upper(way_ids, 1) LOOP
2335 -- select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2337 -- IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2338 -- searchnodes := searchnodes || location.nodes;
2343 -- RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2346 --LANGUAGE plpgsql IMMUTABLE;
2348 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2359 search := ARRAY['ref'];
2362 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2365 select rank_address,name,distance,length(name::text) as namelength
2366 from place_addressline join placex on (address_place_id = placex.place_id)
2367 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2368 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2370 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2371 FOR j IN 1..array_upper(search, 1) LOOP
2372 FOR k IN 1..array_upper(location.name, 1) LOOP
2373 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
2374 result[(100 - location.rank_address)] := trim(location.name[k].value);
2375 found := location.rank_address;
2382 RETURN array_to_string(result,', ');
2387 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2399 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2400 currresult := trim(get_name_by_language(location.name, languagepref));
2401 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2402 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2403 prevresult := currresult;
2407 RETURN array_to_string(result,', ');
2412 DROP TYPE IF EXISTS addressline CASCADE;
2413 create type addressline as (
2420 admin_level INTEGER,
2423 rank_address INTEGER,
2427 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2430 for_place_id BIGINT;
2435 countrylocation RECORD;
2436 searchcountrycode varchar(2);
2437 searchhousenumber TEXT;
2438 searchhousename HSTORE;
2439 searchrankaddress INTEGER;
2440 searchpostcode TEXT;
2447 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2448 WHERE place_id = in_place_id
2449 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2451 IF for_place_id IS NULL THEN
2452 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2453 WHERE place_id = in_place_id
2454 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2457 IF for_place_id IS NULL THEN
2458 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2459 WHERE place_id = in_place_id and rank_address = 30
2460 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2463 IF for_place_id IS NULL THEN
2464 for_place_id := in_place_id;
2465 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2466 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2469 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2472 hadcountry := false;
2474 select placex.place_id, osm_type, osm_id,
2475 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2476 class, type, admin_level, true as fromarea, true as isaddress,
2477 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2478 0 as distance, calculated_country_code, postcode
2480 where place_id = for_place_id
2482 --RAISE WARNING '%',location;
2483 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2484 searchcountrycode := location.calculated_country_code;
2486 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2487 location.isaddress := FALSE;
2489 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2490 searchpostcode := location.postcode;
2492 IF location.rank_address = 4 AND location.isaddress THEN
2495 IF location.rank_address < 4 AND NOT hadcountry THEN
2496 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2497 IF countryname IS NOT NULL THEN
2498 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2499 RETURN NEXT countrylocation;
2502 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2503 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2504 location.distance)::addressline;
2505 RETURN NEXT countrylocation;
2506 found := location.rank_address;
2510 select placex.place_id, osm_type, osm_id,
2511 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2512 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2513 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2514 admin_level, fromarea, isaddress,
2515 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,
2516 distance,calculated_country_code,postcode
2517 from place_addressline join placex on (address_place_id = placex.place_id)
2518 where place_addressline.place_id = for_place_id
2519 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2520 and address_place_id != for_place_id
2521 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2522 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2524 --RAISE WARNING '%',location;
2525 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2526 searchcountrycode := location.calculated_country_code;
2528 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2529 location.isaddress := FALSE;
2531 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2532 searchpostcode := location.postcode;
2534 IF location.rank_address = 4 AND location.isaddress THEN
2537 IF location.rank_address < 4 AND NOT hadcountry THEN
2538 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2539 IF countryname IS NOT NULL THEN
2540 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2541 RETURN NEXT countrylocation;
2544 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2545 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2546 location.distance)::addressline;
2547 RETURN NEXT countrylocation;
2548 found := location.rank_address;
2552 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2553 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2554 IF countryname IS NOT NULL THEN
2555 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2556 RETURN NEXT location;
2560 IF searchcountrycode IS NOT NULL THEN
2561 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2562 RETURN NEXT location;
2565 IF searchhousename IS NOT NULL THEN
2566 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2567 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2568 RETURN NEXT location;
2571 IF searchhousenumber IS NOT NULL THEN
2572 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2573 RETURN NEXT location;
2576 IF searchpostcode IS NOT NULL THEN
2577 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2578 RETURN NEXT location;
2587 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2590 numfeatures integer;
2594 housenumber = place.housenumber,
2595 street = place.street,
2596 addr_place = place.addr_place,
2598 postcode = place.postcode,
2599 country_code = place.country_code,
2600 parent_place_id = null
2602 where placex.place_id = search_place_id
2603 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2604 and place.class = placex.class and place.type = placex.type;
2605 update placex set indexed_status = 2 where place_id = search_place_id;
2606 update placex set indexed_status = 0 where place_id = search_place_id;
2612 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2618 ELSEIF rank < 4 THEN
2620 ELSEIF rank < 8 THEN
2622 ELSEIF rank < 12 THEN
2624 ELSEIF rank < 16 THEN
2626 ELSEIF rank = 16 THEN
2628 ELSEIF rank = 17 THEN
2629 RETURN 'Town / Island';
2630 ELSEIF rank = 18 THEN
2631 RETURN 'Village / Hamlet';
2632 ELSEIF rank = 20 THEN
2634 ELSEIF rank = 21 THEN
2635 RETURN 'Postcode Area';
2636 ELSEIF rank = 22 THEN
2637 RETURN 'Croft / Farm / Locality / Islet';
2638 ELSEIF rank = 23 THEN
2639 RETURN 'Postcode Area';
2640 ELSEIF rank = 25 THEN
2641 RETURN 'Postcode Point';
2642 ELSEIF rank = 26 THEN
2643 RETURN 'Street / Major Landmark';
2644 ELSEIF rank = 27 THEN
2645 RETURN 'Minory Street / Path';
2646 ELSEIF rank = 28 THEN
2647 RETURN 'House / Building';
2649 RETURN 'Other: '||rank;
2656 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2662 ELSEIF rank < 2 THEN
2664 ELSEIF rank < 4 THEN
2666 ELSEIF rank = 5 THEN
2668 ELSEIF rank < 8 THEN
2670 ELSEIF rank < 12 THEN
2672 ELSEIF rank < 16 THEN
2674 ELSEIF rank = 16 THEN
2676 ELSEIF rank = 17 THEN
2677 RETURN 'Town / Village / Hamlet';
2678 ELSEIF rank = 20 THEN
2680 ELSEIF rank = 21 THEN
2681 RETURN 'Postcode Area';
2682 ELSEIF rank = 22 THEN
2683 RETURN 'Croft / Farm / Locality / Islet';
2684 ELSEIF rank = 23 THEN
2685 RETURN 'Postcode Area';
2686 ELSEIF rank = 25 THEN
2687 RETURN 'Postcode Point';
2688 ELSEIF rank = 26 THEN
2689 RETURN 'Street / Major Landmark';
2690 ELSEIF rank = 27 THEN
2691 RETURN 'Minory Street / Path';
2692 ELSEIF rank = 28 THEN
2693 RETURN 'House / Building';
2695 RETURN 'Other: '||rank;
2702 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2709 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2710 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2717 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2725 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2727 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2728 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2730 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2738 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2739 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2744 place_centroid GEOMETRY;
2745 out_partition INTEGER;
2746 out_parent_place_id BIGINT;
2748 address_street_word_id INTEGER;
2753 place_centroid := ST_Centroid(pointgeo);
2754 out_partition := get_partition(in_countrycode);
2755 out_parent_place_id := null;
2757 address_street_word_id := get_name_id(make_standard_name(in_street));
2758 IF address_street_word_id IS NOT NULL THEN
2759 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2760 out_parent_place_id := location.place_id;
2764 IF out_parent_place_id IS NULL THEN
2765 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2766 out_parent_place_id := location.place_id;
2770 out_postcode := in_postcode;
2771 IF out_postcode IS NULL THEN
2772 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2774 IF out_postcode IS NULL THEN
2775 out_postcode := getNearestPostcode(out_partition, place_centroid);
2779 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2780 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2781 newpoints := newpoints + 1;
2788 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2795 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2796 IF members[i+1] = member THEN
2797 result := result || members[i];
2806 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2812 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2813 IF members[i+1] = ANY(memberLabels) THEN
2814 RETURN NEXT members[i];
2823 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2824 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2826 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2827 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
2828 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2829 ), '') AS bytea), 'UTF8');
2831 LANGUAGE SQL IMMUTABLE STRICT;
2833 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2837 RETURN decode_url_part(p);
2839 WHEN others THEN return null;
2842 LANGUAGE plpgsql IMMUTABLE;
2844 DROP TYPE wikipedia_article_match CASCADE;
2845 create type wikipedia_article_match as (
2851 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2857 wiki_article_title TEXT;
2858 wiki_article_language TEXT;
2859 result wikipedia_article_match;
2861 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'];
2863 WHILE langs[i] IS NOT NULL LOOP
2864 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2865 IF wiki_article is not null THEN
2866 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2867 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2868 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2869 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2870 wiki_article := replace(wiki_article,' ','_');
2871 IF strpos(wiki_article, ':') IN (3,4) THEN
2872 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2873 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2875 wiki_article_title := trim(wiki_article);
2876 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;
2879 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2880 from wikipedia_article
2881 where language = wiki_article_language and
2882 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2884 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2885 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2886 where wikipedia_redirect.language = wiki_article_language and
2887 (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'\\',''))
2888 order by importance desc limit 1 INTO result;
2890 IF result.language is not null THEN
2901 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2902 RETURNS SETOF GEOMETRY
2916 remainingdepth INTEGER;
2921 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2923 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2924 RETURN NEXT geometry;
2928 remainingdepth := maxdepth - 1;
2929 area := ST_AREA(geometry);
2930 IF remainingdepth < 1 OR area < maxarea THEN
2931 RETURN NEXT geometry;
2935 xmin := st_xmin(geometry);
2936 xmax := st_xmax(geometry);
2937 ymin := st_ymin(geometry);
2938 ymax := st_ymax(geometry);
2939 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2941 -- if the geometry completely covers the box don't bother to slice any more
2942 IF ST_AREA(secbox) = area THEN
2943 RETURN NEXT geometry;
2947 xmid := (xmin+xmax)/2;
2948 ymid := (ymin+ymax)/2;
2951 FOR seg IN 1..4 LOOP
2954 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2957 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2960 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2963 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2966 IF st_intersects(geometry, secbox) THEN
2967 secgeo := st_intersection(geometry, secbox);
2968 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2969 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2970 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2972 RETURN NEXT geo.geom;
2984 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2985 RETURNS SETOF GEOMETRY
2990 -- 10000000000 is ~~ 1x1 degree
2991 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2992 RETURN NEXT geo.geom;
3000 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
3004 osmtype character(1);
3008 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
3009 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3010 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3011 -- force delete from place/placex by making it a very small geometry
3012 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;
3013 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
3020 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
3028 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
3029 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
3030 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
3031 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
3032 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
3033 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3034 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));
3035 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3036 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));
3042 ELSEIF rank < 18 THEN
3044 ELSEIF rank < 20 THEN
3046 ELSEIF rank = 21 THEN
3048 ELSEIF rank < 24 THEN
3050 ELSEIF rank < 26 THEN
3051 diameter := 0.002; -- 100 to 200 meters
3052 ELSEIF rank < 28 THEN
3053 diameter := 0.001; -- 50 to 100 meters
3055 IF diameter > 0 THEN
3057 -- roads may cause reparenting for >27 rank places
3058 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3059 ELSEIF rank >= 16 THEN
3060 -- up to rank 16, street-less addresses may need reparenting
3061 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);
3063 -- for all other places the search terms may change as well
3064 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);