1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
8 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
15 LANGUAGE plpgsql IMMUTABLE;
17 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
23 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
29 LANGUAGE plpgsql IMMUTABLE;
31 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
37 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
38 NEWgeometry := ST_buffer(NEWgeometry,0);
39 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
40 RETURN ST_SetSRID(ST_Point(0,0),4326);
46 LANGUAGE plpgsql IMMUTABLE;
48 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
53 -- RAISE WARNING '%',place;
54 NEWgeometry := ST_PointOnSurface(place);
55 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
56 -- NEWgeometry := ST_buffer(NEWgeometry,0);
57 -- IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
61 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
64 LANGUAGE plpgsql IMMUTABLE;
66 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
67 AS '{modulepath}/nominatim.so', 'transliteration'
68 LANGUAGE c IMMUTABLE STRICT;
70 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
71 AS '{modulepath}/nominatim.so', 'gettokenstring'
72 LANGUAGE c IMMUTABLE STRICT;
74 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
79 o := gettokenstring(transliteration(name));
80 RETURN trim(substr(o,1,length(o)));
83 LANGUAGE 'plpgsql' IMMUTABLE;
85 -- returns NULL if the word is too common
86 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
91 return_word_id INTEGER;
94 lookup_token := trim(lookup_word);
95 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
96 IF return_word_id IS NULL THEN
97 return_word_id := nextval('seq_word');
98 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
100 IF count > get_maxwordfreq() THEN
101 return_word_id := NULL;
104 RETURN return_word_id;
109 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
114 return_word_id INTEGER;
116 lookup_token := ' '||trim(lookup_word);
117 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
118 IF return_word_id IS NULL THEN
119 return_word_id := nextval('seq_word');
120 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
122 RETURN return_word_id;
127 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
132 return_word_id INTEGER;
134 lookup_token := ' '||trim(lookup_word);
135 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
136 IF return_word_id IS NULL THEN
137 return_word_id := nextval('seq_word');
138 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
140 RETURN return_word_id;
145 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
150 return_word_id INTEGER;
152 lookup_token := ' '||trim(lookup_word);
153 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
154 IF return_word_id IS NULL THEN
155 return_word_id := nextval('seq_word');
156 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
168 return_word_id INTEGER;
170 lookup_token := lookup_class||'='||lookup_type;
171 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
172 IF return_word_id IS NULL THEN
173 return_word_id := nextval('seq_word');
174 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
176 RETURN return_word_id;
181 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
186 return_word_id INTEGER;
188 lookup_token := lookup_class||'='||lookup_type;
189 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
190 RETURN return_word_id;
195 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
200 return_word_id INTEGER;
202 lookup_token := ' '||trim(lookup_word);
203 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
204 IF return_word_id IS NULL THEN
205 return_word_id := nextval('seq_word');
206 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
208 RETURN return_word_id;
213 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
218 nospace_lookup_token TEXT;
219 return_word_id INTEGER;
221 lookup_token := ' '||trim(lookup_word);
222 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
223 IF return_word_id IS NULL THEN
224 return_word_id := nextval('seq_word');
225 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
226 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
227 -- IF ' '||nospace_lookup_token != lookup_token THEN
228 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
231 RETURN return_word_id;
236 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
241 RETURN getorcreate_name_id(lookup_word, '');
246 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
251 return_word_id INTEGER;
253 lookup_token := trim(lookup_word);
254 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
255 RETURN return_word_id;
258 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
265 return_word_id INTEGER;
267 lookup_token := ' '||trim(lookup_word);
268 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
269 RETURN return_word_id;
272 LANGUAGE plpgsql IMMUTABLE;
274 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
279 return_word_ids INTEGER[];
281 lookup_token := ' '||trim(lookup_word);
282 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
283 RETURN return_word_ids;
286 LANGUAGE plpgsql IMMUTABLE;
288 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
295 IF array_upper(a, 1) IS NULL THEN
298 IF array_upper(b, 1) IS NULL THEN
302 FOR i IN 1..array_upper(b, 1) LOOP
303 IF NOT (ARRAY[b[i]] <@ r) THEN
310 LANGUAGE plpgsql IMMUTABLE;
312 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
321 FOR item IN SELECT (each(src)).* LOOP
323 s := make_standard_name(item.value);
324 w := getorcreate_country(s, lookup_country_code);
326 words := regexp_split_to_array(item.value, E'[,;()]');
327 IF array_upper(words, 1) != 1 THEN
328 FOR j IN 1..array_upper(words, 1) LOOP
329 s := make_standard_name(words[j]);
331 w := getorcreate_country(s, lookup_country_code);
340 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
350 result := '{}'::INTEGER[];
352 FOR item IN SELECT (each(src)).* LOOP
354 s := make_standard_name(item.value);
356 w := getorcreate_name_id(s, item.value);
358 IF not(ARRAY[w] <@ result) THEN
359 result := result || w;
362 w := getorcreate_word_id(s);
364 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
365 result := result || w;
368 words := string_to_array(s, ' ');
369 IF array_upper(words, 1) IS NOT NULL THEN
370 FOR j IN 1..array_upper(words, 1) LOOP
371 IF (words[j] != '') THEN
372 w = getorcreate_word_id(words[j]);
373 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
374 result := result || w;
380 words := regexp_split_to_array(item.value, E'[,;()]');
381 IF array_upper(words, 1) != 1 THEN
382 FOR j IN 1..array_upper(words, 1) LOOP
383 s := make_standard_name(words[j]);
385 w := getorcreate_word_id(s);
386 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
387 result := result || w;
393 s := regexp_replace(item.value, '市$', '');
394 IF s != item.value THEN
395 s := make_standard_name(s);
397 w := getorcreate_name_id(s, item.value);
398 IF NOT (ARRAY[w] <@ result) THEN
399 result := result || w;
409 LANGUAGE plpgsql IMMUTABLE;
411 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
421 result := '{}'::INTEGER[];
423 s := make_standard_name(src);
424 w := getorcreate_name_id(s, src);
426 IF NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 w := getorcreate_word_id(s);
432 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
433 result := result || w;
436 words := string_to_array(s, ' ');
437 IF array_upper(words, 1) IS NOT NULL THEN
438 FOR j IN 1..array_upper(words, 1) LOOP
439 IF (words[j] != '') THEN
440 w = getorcreate_word_id(words[j]);
441 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
442 result := result || w;
448 words := regexp_split_to_array(src, E'[,;()]');
449 IF array_upper(words, 1) != 1 THEN
450 FOR j IN 1..array_upper(words, 1) LOOP
451 s := make_standard_name(words[j]);
453 w := getorcreate_word_id(s);
454 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
455 result := result || w;
461 s := regexp_replace(src, '市$', '');
463 s := make_standard_name(s);
465 w := getorcreate_name_id(s, src);
466 IF NOT (ARRAY[w] <@ result) THEN
467 result := result || w;
475 LANGUAGE plpgsql IMMUTABLE;
477 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
480 place_centre GEOMETRY;
483 place_centre := ST_PointOnSurface(place);
485 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
487 -- Try for a OSM polygon
488 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
490 RETURN nearcountry.country_code;
493 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
495 -- Try for OSM fallback data
496 -- The order is to deal with places like HongKong that are 'states' within another polygon
497 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
499 RETURN nearcountry.country_code;
502 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
504 -- Natural earth data
505 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
507 RETURN nearcountry.country_code;
510 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
513 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
515 RETURN nearcountry.country_code;
518 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
520 -- Natural earth data
521 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
523 RETURN nearcountry.country_code;
529 LANGUAGE plpgsql IMMUTABLE;
531 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
536 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
538 RETURN lower(nearcountry.country_default_language_code);
543 LANGUAGE plpgsql IMMUTABLE;
545 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
550 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
552 RETURN lower(nearcountry.country_default_language_codes);
557 LANGUAGE plpgsql IMMUTABLE;
559 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
564 FOR nearcountry IN select partition from country_name where country_code = in_country_code
566 RETURN nearcountry.partition;
571 LANGUAGE plpgsql IMMUTABLE;
573 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
577 DELETE FROM location_area where place_id = OLD_place_id;
578 -- TODO:location_area
584 CREATE OR REPLACE FUNCTION add_location(
586 country_code varchar(2),
590 rank_address INTEGER,
605 IF rank_search > 25 THEN
606 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
609 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
611 x := deleteLocationArea(partition, place_id, rank_search);
614 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
617 centroid := ST_Centroid(geometry);
619 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
620 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
623 ELSEIF rank_search < 26 THEN
626 IF rank_address = 0 THEN
628 ELSEIF rank_search <= 14 THEN
630 ELSEIF rank_search <= 15 THEN
632 ELSEIF rank_search <= 16 THEN
634 ELSEIF rank_search <= 17 THEN
636 ELSEIF rank_search <= 21 THEN
638 ELSEIF rank_search = 25 THEN
642 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
644 secgeo := ST_Buffer(geometry, diameter);
645 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
650 secgeo := ST_Buffer(geometry, 0.0002);
651 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
654 secgeo := ST_Buffer(geometry, 0.001);
655 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
664 CREATE OR REPLACE FUNCTION update_location(
667 place_country_code varchar(2),
670 rank_address INTEGER,
678 b := deleteLocationArea(partition, place_id, rank_search);
679 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
680 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
685 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
696 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
697 FOR childplace IN select * from search_name,place_addressline
698 where address_place_id = parent_place_id
699 and search_name.place_id = place_addressline.place_id
701 delete from search_name where place_id = childplace.place_id;
702 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
703 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
705 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
706 childplace.name_vector := childplace.name_vector || to_add;
708 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
709 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
710 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
718 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
721 newkeywords INTEGER[];
722 addedkeywords INTEGER[];
723 removedkeywords INTEGER[];
727 newkeywords := make_keywords(name);
728 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
729 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
730 where place_id = OLD_place_id into addedkeywords, removedkeywords;
732 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
734 IF #removedkeywords > 0 THEN
735 -- abort due to tokens removed
739 IF #addedkeywords > 0 THEN
740 -- short circuit - no changes
744 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
745 RETURN search_name_add_words(OLD_place_id, addedkeywords);
751 CREATE OR REPLACE FUNCTION create_interpolation(wayid BIGINT, interpolationtype TEXT) RETURNS INTEGER
763 orginalstartnumber INTEGER;
764 originalnumberrange INTEGER;
769 search_place_id BIGINT;
773 IF interpolationtype = 'odd' OR interpolationtype = 'even' THEN
775 ELSEIF interpolationtype = 'all' THEN
777 ELSEIF interpolationtype ~ '^\d+$' THEN
778 stepsize := interpolationtype::INTEGER;
783 select nodes from planet_osm_ways where id = wayid INTO waynodes;
785 IF array_upper(waynodes, 1) IS NULL THEN
789 select postcode, geometry from placex where osm_type = 'W' and osm_id = wayid
790 INTO defpostalcode, linegeo;
792 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
799 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
801 -- If there is a place of a type other than place/house, use that because
802 -- it is guaranteed to be the original node. For place/house types use the
803 -- one with the smallest id because the original node was created first.
804 -- Ignore all nodes marked for deletion. (Might happen when the type changes.)
805 select place_id from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT and indexed_status < 100 order by (type = 'house'),place_id limit 1 INTO search_place_id;
806 IF search_place_id IS NOT NULL THEN
807 select * from placex where place_id = search_place_id INTO nextnode;
809 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
810 -- Make sure that the point is actually on the line. That might
811 -- be a bit paranoid but ensures that the algorithm still works
812 -- should osm2pgsql attempt to repair geometries.
813 splitline := split_line_on_node(linegeo, nextnode.geometry);
814 sectiongeo := ST_GeometryN(splitline, 1);
815 linegeo := ST_GeometryN(splitline, 2);
817 sectiongeo = linegeo;
819 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
821 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
822 AND @(startnumber - endnumber) < 1000 AND startnumber != endnumber
823 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
825 IF (startnumber > endnumber) THEN
826 housenum := endnumber;
827 endnumber := startnumber;
828 startnumber := housenum;
829 sectiongeo := ST_Reverse(sectiongeo);
831 orginalstartnumber := startnumber;
832 originalnumberrange := endnumber - startnumber;
834 startnumber := startnumber + stepsize;
835 -- correct for odd/even
836 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
837 startnumber := startnumber - 1;
839 endnumber := endnumber - 1;
841 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
842 FOR housenum IN startnumber..endnumber BY stepsize LOOP
843 -- this should really copy postcodes but it puts a huge burden on
844 -- the system for no big benefit ideally postcodes should move up to the way
845 insert into placex (osm_type, osm_id, class, type, admin_level,
846 housenumber, street, addr_place, isin, postcode,
847 country_code, parent_place_id, rank_address, rank_search,
848 indexed_status, geometry)
849 values ('N', prevnode.osm_id, 'place', 'house', prevnode.admin_level,
850 housenum, prevnode.street, prevnode.addr_place, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
851 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search,
852 1, ST_LineInterpolatePoint(sectiongeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
853 newpoints := newpoints + 1;
854 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
858 -- early break if we are out of line string,
859 -- might happen when a line string loops back on itself
860 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
864 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
865 prevnode := nextnode;
869 --RAISE WARNING 'interpolation points % ',newpoints;
876 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
882 country_code VARCHAR(2);
883 default_language VARCHAR(10);
887 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
889 -- remove operator tag for most places, messes too much with search_name indexes
890 IF NEW.class not in ('amenity', 'shop') THEN
891 NEW.name := delete(NEW.name, 'operator');
895 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
896 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
900 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
901 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
902 RAISE WARNING 'invalid geometry %',NEW.osm_id;
906 IF NEW.osm_type = 'R' THEN
907 -- invalid multipolygons can crash postgis, don't even bother to try!
910 NEW.geometry := ST_buffer(NEW.geometry,0);
911 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
912 RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
917 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
919 NEW.place_id := nextval('seq_place');
920 NEW.indexed_status := 1; --STATUS_NEW
922 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
924 NEW.partition := get_partition(NEW.calculated_country_code);
925 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
927 -- copy 'name' to or from the default language (if there is a default language)
928 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
929 default_language := get_country_language_code(NEW.calculated_country_code);
930 IF default_language IS NOT NULL THEN
931 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
932 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
933 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
934 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
939 IF NEW.admin_level > 15 THEN
940 NEW.admin_level := 15;
943 IF NEW.housenumber IS NOT NULL THEN
944 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
947 IF NEW.osm_type = 'X' THEN
948 -- E'X'ternal records should already be in the right format so do nothing
950 NEW.rank_search := 30;
951 NEW.rank_address := NEW.rank_search;
953 -- By doing in postgres we have the country available to us - currently only used for postcode
954 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
956 IF NEW.postcode IS NULL THEN
957 -- most likely just a part of a multipolygon postcode boundary, throw it away
961 NEW.name := hstore('ref', NEW.postcode);
963 IF NEW.calculated_country_code = 'gb' THEN
965 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
966 NEW.rank_search := 25;
967 NEW.rank_address := 5;
968 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
969 NEW.rank_search := 23;
970 NEW.rank_address := 5;
971 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
972 NEW.rank_search := 21;
973 NEW.rank_address := 5;
976 ELSEIF NEW.calculated_country_code = 'sg' THEN
978 IF NEW.postcode ~ '^([0-9]{6})$' THEN
979 NEW.rank_search := 25;
980 NEW.rank_address := 11;
983 ELSEIF NEW.calculated_country_code = 'de' THEN
985 IF NEW.postcode ~ '^([0-9]{5})$' THEN
986 NEW.rank_search := 21;
987 NEW.rank_address := 11;
991 -- Guess at the postcode format and coverage (!)
992 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
993 NEW.rank_search := 21;
994 NEW.rank_address := 11;
996 -- Does it look splitable into and area and local code?
997 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
999 IF postcode IS NOT NULL THEN
1000 NEW.rank_search := 25;
1001 NEW.rank_address := 11;
1002 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
1003 NEW.rank_search := 21;
1004 NEW.rank_address := 11;
1009 ELSEIF NEW.class = 'place' THEN
1010 IF NEW.type in ('continent') THEN
1011 NEW.rank_search := 2;
1012 NEW.rank_address := NEW.rank_search;
1013 NEW.calculated_country_code := NULL;
1014 ELSEIF NEW.type in ('sea') THEN
1015 NEW.rank_search := 2;
1016 NEW.rank_address := 0;
1017 NEW.calculated_country_code := NULL;
1018 ELSEIF NEW.type in ('country') THEN
1019 NEW.rank_search := 4;
1020 NEW.rank_address := NEW.rank_search;
1021 ELSEIF NEW.type in ('state') THEN
1022 NEW.rank_search := 8;
1023 NEW.rank_address := NEW.rank_search;
1024 ELSEIF NEW.type in ('region') THEN
1025 NEW.rank_search := 18; -- dropped from previous value of 10
1026 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1027 ELSEIF NEW.type in ('county') THEN
1028 NEW.rank_search := 12;
1029 NEW.rank_address := NEW.rank_search;
1030 ELSEIF NEW.type in ('city') THEN
1031 NEW.rank_search := 16;
1032 NEW.rank_address := NEW.rank_search;
1033 ELSEIF NEW.type in ('island') THEN
1034 NEW.rank_search := 17;
1035 NEW.rank_address := 0;
1036 ELSEIF NEW.type in ('town') THEN
1037 NEW.rank_search := 18;
1038 NEW.rank_address := 16;
1039 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1040 NEW.rank_search := 19;
1041 NEW.rank_address := 16;
1042 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
1043 NEW.rank_search := 20;
1044 NEW.rank_address := NEW.rank_search;
1045 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
1046 NEW.rank_search := 20;
1047 NEW.rank_address := 0;
1048 -- Irish townlands, tagged as place=locality and locality=townland
1049 IF (NEW.extratags -> 'locality') = 'townland' THEN
1050 NEW.rank_address := 20;
1052 ELSEIF NEW.type in ('neighbourhood') THEN
1053 NEW.rank_search := 22;
1054 NEW.rank_address := 22;
1055 ELSEIF NEW.type in ('house','building') THEN
1056 NEW.rank_search := 30;
1057 NEW.rank_address := NEW.rank_search;
1058 ELSEIF NEW.type in ('houses') THEN
1059 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1060 -- insert new point into place for each derived building
1061 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1062 NEW.rank_search := 28;
1063 NEW.rank_address := 0;
1066 ELSEIF NEW.class = 'boundary' THEN
1067 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1068 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1071 NEW.rank_search := NEW.admin_level * 2;
1072 IF NEW.type = 'administrative' THEN
1073 NEW.rank_address := NEW.rank_search;
1075 NEW.rank_address := 0;
1077 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1078 NEW.rank_search := 22;
1079 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
1080 NEW.rank_address := NEW.rank_search;
1082 NEW.rank_address := 0;
1084 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
1085 NEW.rank_search := 18;
1086 NEW.rank_address := 0;
1087 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1088 NEW.rank_search := 4;
1089 NEW.rank_address := NEW.rank_search;
1090 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1092 -- any feature more than 5 square miles is probably worth indexing
1093 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1094 NEW.rank_search := 22;
1095 NEW.rank_address := 0;
1096 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1097 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1098 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1100 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1102 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1104 ELSEIF NEW.class = 'waterway' THEN
1105 IF NEW.osm_type = 'R' THEN
1106 NEW.rank_search := 16;
1108 NEW.rank_search := 17;
1110 NEW.rank_address := 0;
1111 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
1112 NEW.rank_search := 27;
1113 NEW.rank_address := NEW.rank_search;
1114 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1115 NEW.rank_search := 26;
1116 NEW.rank_address := NEW.rank_search;
1117 ELSEIF NEW.class = 'mountain_pass' THEN
1118 NEW.rank_search := 20;
1119 NEW.rank_address := 0;
1124 IF NEW.rank_search > 30 THEN
1125 NEW.rank_search := 30;
1128 IF NEW.rank_address > 30 THEN
1129 NEW.rank_address := 30;
1132 IF (NEW.extratags -> 'capital') = 'yes' THEN
1133 NEW.rank_search := NEW.rank_search - 1;
1136 -- a country code make no sense below rank 4 (country)
1137 IF NEW.rank_search < 4 THEN
1138 NEW.calculated_country_code := NULL;
1141 -- Block import below rank 22
1142 -- IF NEW.rank_search > 22 THEN
1146 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1148 RETURN NEW; -- @DIFFUPDATES@ The following is not needed until doing diff updates, and slows the main index process down
1150 IF NEW.rank_address > 0 THEN
1151 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1152 -- Performance: We just can't handle re-indexing for country level changes
1153 IF st_area(NEW.geometry) < 1 THEN
1154 -- mark items within the geometry for re-indexing
1155 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1157 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1158 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1159 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));
1160 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1161 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));
1164 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1166 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1167 IF NEW.type='postcode' THEN
1169 ELSEIF NEW.rank_search < 16 THEN
1171 ELSEIF NEW.rank_search < 18 THEN
1173 ELSEIF NEW.rank_search < 20 THEN
1175 ELSEIF NEW.rank_search = 21 THEN
1177 ELSEIF NEW.rank_search < 24 THEN
1179 ELSEIF NEW.rank_search < 26 THEN
1180 diameter := 0.002; -- 100 to 200 meters
1181 ELSEIF NEW.rank_search < 28 THEN
1182 diameter := 0.001; -- 50 to 100 meters
1184 IF diameter > 0 THEN
1185 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1186 IF NEW.rank_search >= 26 THEN
1187 -- roads may cause reparenting for >27 rank places
1188 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1189 ELSEIF NEW.rank_search >= 16 THEN
1190 -- up to rank 16, street-less addresses may need reparenting
1191 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);
1193 -- for all other places the search terms may change as well
1194 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);
1200 -- add to tables for special search
1201 -- Note: won't work on initial import because the classtype tables
1202 -- do not yet exist. It won't hurt either.
1203 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1204 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1206 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1207 USING NEW.place_id, ST_Centroid(NEW.geometry);
1211 -- IF NEW.rank_search < 26 THEN
1212 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1221 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1226 place_centroid GEOMETRY;
1228 search_maxdistance FLOAT[];
1229 search_mindistance FLOAT[];
1230 address_havelevel BOOLEAN[];
1237 relation_members TEXT[];
1239 linkedplacex RECORD;
1240 search_diameter FLOAT;
1241 search_prevdiameter FLOAT;
1242 search_maxrank INTEGER;
1243 address_maxrank INTEGER;
1244 address_street_word_id INTEGER;
1245 address_street_word_ids INTEGER[];
1246 parent_place_id_rank BIGINT;
1251 location_rank_search INTEGER;
1252 location_distance FLOAT;
1253 location_parent GEOMETRY;
1254 location_isaddress BOOLEAN;
1258 default_language TEXT;
1259 name_vector INTEGER[];
1260 nameaddress_vector INTEGER[];
1262 linked_node_id BIGINT;
1268 IF OLD.indexed_status = 100 THEN
1269 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1270 delete from placex where place_id = OLD.place_id;
1274 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1278 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1280 --RAISE WARNING '%',NEW.place_id;
1281 --RAISE WARNING '%', NEW;
1283 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1284 -- Silently do nothing
1288 -- TODO: this test is now redundant?
1289 IF OLD.indexed_status != 0 THEN
1291 NEW.indexed_date = now();
1293 result := deleteSearchName(NEW.partition, NEW.place_id);
1294 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1295 result := deleteRoad(NEW.partition, NEW.place_id);
1296 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1297 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1299 IF NEW.linked_place_id is not null THEN
1303 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1304 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1308 -- Speed up searches - just use the centroid of the feature
1309 -- cheaper but less acurate
1310 place_centroid := ST_PointOnSurface(NEW.geometry);
1311 NEW.centroid := null;
1313 -- recalculate country and partition
1314 IF NEW.rank_search = 4 THEN
1315 -- for countries, believe the mapped country code,
1316 -- so that we remain in the right partition if the boundaries
1318 NEW.partition := get_partition(lower(NEW.country_code));
1319 IF NEW.partition = 0 THEN
1320 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1321 NEW.partition := get_partition(NEW.calculated_country_code);
1323 NEW.calculated_country_code := lower(NEW.country_code);
1326 IF NEW.rank_search > 4 THEN
1327 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1328 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1330 NEW.calculated_country_code := NULL;
1332 NEW.partition := get_partition(NEW.calculated_country_code);
1334 NEW.geometry_sector := geometry_sector(NEW.partition, place_centroid);
1336 -- waterway ways are linked when they are part of a relation and have the same class/type
1337 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1338 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1340 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1341 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1342 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1343 FOR linked_node_id IN SELECT place_id FROM placex
1344 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1345 and class = NEW.class and type = NEW.type
1346 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1348 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1355 -- Adding ourselves to the list simplifies address calculations later
1356 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1358 -- What level are we searching from
1359 search_maxrank := NEW.rank_search;
1361 -- Thought this wasn't needed but when we add new languages to the country_name table
1362 -- we need to update the existing names
1363 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1364 default_language := get_country_language_code(NEW.calculated_country_code);
1365 IF default_language IS NOT NULL THEN
1366 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1367 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1368 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1369 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1374 -- Initialise the name vector using our name
1375 name_vector := make_keywords(NEW.name);
1376 nameaddress_vector := '{}'::int[];
1378 -- some tag combinations add a special id for search
1379 tagpairid := get_tagpair(NEW.class,NEW.type);
1380 IF tagpairid IS NOT NULL THEN
1381 name_vector := name_vector + tagpairid;
1385 address_havelevel[i] := false;
1388 NEW.importance := null;
1389 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1390 IF NEW.importance IS NULL THEN
1391 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;
1394 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1396 -- For low level elements we inherit from our parent road
1397 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1399 --RAISE WARNING 'finding street for %', NEW;
1401 -- We won't get a better centroid, besides these places are too small to care
1402 NEW.centroid := place_centroid;
1404 NEW.parent_place_id := null;
1406 -- to do that we have to find our parent road
1407 -- Copy data from linked items (points on ways, addr:street links, relations)
1408 -- Note that addr:street links can only be indexed once the street itself is indexed
1409 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1411 -- if there is no address information, see if we can get it from a surrounding building
1412 IF NEW.street IS NULL AND NEW.addr_place IS NULL AND NEW.housenumber IS NULL THEN
1413 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')
1415 NEW.housenumber := location.housenumber;
1416 NEW.street := location.street;
1417 NEW.addr_place := location.addr_place;
1421 -- Is this node part of a relation?
1422 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['n'||NEW.osm_id]
1424 -- At the moment we only process one type of relation - associatedStreet
1425 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1426 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1427 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1428 --RAISE WARNING 'node in relation %',relation;
1429 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1430 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1436 --RAISE WARNING 'x1';
1437 -- Is this node part of a way?
1438 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id] LOOP
1439 --RAISE WARNING '%', way;
1440 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1442 --RAISE WARNING '%', location;
1443 -- Way IS a road then we are on it - that must be our road
1444 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1445 --RAISE WARNING 'node in way that is a street %',location;
1446 NEW.parent_place_id := location.place_id;
1449 -- Is the WAY part of a relation
1450 IF NEW.parent_place_id IS NULL THEN
1451 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1453 -- At the moment we only process one type of relation - associatedStreet
1454 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1455 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1456 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1457 --RAISE WARNING 'node in way that is in a relation %',relation;
1458 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1459 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1466 -- If the way contains an explicit name of a street copy it
1467 -- Slightly less strict then above because data is copied from any object.
1468 IF NEW.street IS NULL AND NEW.addr_place IS NULL THEN
1469 --RAISE WARNING 'node in way that has a streetname %',location;
1470 NEW.street := location.street;
1471 NEW.addr_place := location.addr_place;
1474 -- If this way is a street interpolation line then it is probably as good as we are going to get
1475 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
1476 -- Try and find a way that is close roughly parellel to this line
1477 FOR relation IN SELECT place_id FROM placex
1478 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1479 and st_geometrytype(location.geometry) in ('ST_LineString')
1480 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0))+
1481 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,0.5))+
1482 ST_distance(placex.geometry, ST_LineInterpolatePoint(location.geometry,1))) ASC limit 1
1484 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1485 NEW.parent_place_id := relation.place_id;
1494 --RAISE WARNING 'x2';
1496 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1497 -- Is this way part of a relation?
1498 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY['w'||NEW.osm_id]
1500 -- At the moment we only process one type of relation - associatedStreet
1501 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1502 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1503 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1504 --RAISE WARNING 'way that is in a relation %',relation;
1505 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1506 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1513 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1515 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1516 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1517 IF address_street_word_ids IS NOT NULL THEN
1518 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1519 NEW.parent_place_id := location.place_id;
1524 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1525 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1526 IF address_street_word_ids IS NOT NULL THEN
1527 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1528 NEW.parent_place_id := location.place_id;
1533 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1534 -- Still nothing, just use the nearest road
1535 IF NEW.parent_place_id IS NULL THEN
1536 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1537 NEW.parent_place_id := location.place_id;
1542 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1544 -- If we didn't find any road fallback to standard method
1545 IF NEW.parent_place_id IS NOT NULL THEN
1547 -- Add the street to the address as zero distance to force to front of list
1548 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1549 address_havelevel[26] := true;
1551 -- Import address details from parent, reclculating distance in process
1552 -- 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
1553 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1554 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1556 -- Get the details of the parent road
1557 select * from search_name where place_id = NEW.parent_place_id INTO location;
1558 NEW.calculated_country_code := location.country_code;
1560 --RAISE WARNING '%', NEW.name;
1561 -- If there is no name it isn't searchable, don't bother to create a search record
1562 IF NEW.name is NULL THEN
1566 -- Merge address from parent
1567 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1568 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1570 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1571 -- Just be happy with inheriting from parent road only
1573 IF NEW.rank_search <= 25 THEN
1574 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1577 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);
1584 -- RAISE WARNING ' INDEXING Started:';
1585 -- RAISE WARNING ' INDEXING: %',NEW;
1587 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1589 -- see if we have any special relation members
1590 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1592 -- RAISE WARNING 'get_osm_rel_members, label';
1593 IF relation_members IS NOT NULL THEN
1594 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1596 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1597 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1599 -- If we don't already have one use this as the centre point of the geometry
1600 IF NEW.centroid IS NULL THEN
1601 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1604 -- merge in the label name, re-init word vector
1605 IF NOT linkedPlacex.name IS NULL THEN
1606 NEW.name := linkedPlacex.name || NEW.name;
1607 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1610 -- merge in extra tags
1611 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1613 -- mark the linked place (excludes from search results)
1614 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1616 -- keep a note of the node id in case we need it for wikipedia in a bit
1617 linked_node_id := linkedPlacex.osm_id;
1622 IF NEW.centroid IS NULL THEN
1624 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1626 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1627 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1629 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1630 -- But that can be fixed by explicitly setting the label in the data
1631 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1632 AND NEW.rank_address = linkedPlacex.rank_address THEN
1634 -- If we don't already have one use this as the centre point of the geometry
1635 IF NEW.centroid IS NULL THEN
1636 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1639 -- merge in the name, re-init word vector
1640 IF NOT linkedPlacex.name IS NULL THEN
1641 NEW.name := linkedPlacex.name || NEW.name;
1642 name_vector := make_keywords(NEW.name);
1645 -- merge in extra tags
1646 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1648 -- mark the linked place (excludes from search results)
1649 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1651 -- keep a note of the node id in case we need it for wikipedia in a bit
1652 linked_node_id := linkedPlacex.osm_id;
1664 -- Name searches can be done for ways as well as relations
1665 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 THEN
1667 -- not found one yet? how about doing a name search
1668 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1670 FOR linkedPlacex IN select placex.* from placex WHERE
1671 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1672 AND placex.rank_address = NEW.rank_address
1673 AND placex.place_id != NEW.place_id
1674 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1675 AND st_covers(NEW.geometry, placex.geometry)
1678 -- If we don't already have one use this as the centre point of the geometry
1679 IF NEW.centroid IS NULL THEN
1680 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1683 -- merge in the name, re-init word vector
1684 NEW.name := linkedPlacex.name || NEW.name;
1685 name_vector := make_keywords(NEW.name);
1687 -- merge in extra tags
1688 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1690 -- mark the linked place (excludes from search results)
1691 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1693 -- keep a note of the node id in case we need it for wikipedia in a bit
1694 linked_node_id := linkedPlacex.osm_id;
1698 IF NEW.centroid IS NOT NULL THEN
1699 place_centroid := NEW.centroid;
1700 -- Place might have had only a name tag before but has now received translations
1701 -- from the linked place. Make sure a name tag for the default language exists in
1703 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1704 default_language := get_country_language_code(NEW.calculated_country_code);
1705 IF default_language IS NOT NULL THEN
1706 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1707 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1708 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1709 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1715 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1716 IF NEW.importance is null THEN
1717 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1719 -- Still null? how about looking it up by the node id
1720 IF NEW.importance IS NULL THEN
1721 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;
1726 -- make sure all names are in the word table
1727 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1728 perform create_country(NEW.name, lower(NEW.country_code));
1731 NEW.parent_place_id = 0;
1732 parent_place_id_rank = 0;
1734 -- convert isin to array of tokenids
1735 isin_tokens := '{}'::int[];
1736 IF NEW.isin IS NOT NULL THEN
1737 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1738 IF array_upper(isin, 1) IS NOT NULL THEN
1739 FOR i IN 1..array_upper(isin, 1) LOOP
1740 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1741 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1742 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1743 isin_tokens := isin_tokens || address_street_word_id;
1746 -- merge word into address vector
1747 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1748 IF address_street_word_id IS NOT NULL THEN
1749 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1754 IF NEW.postcode IS NOT NULL THEN
1755 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1756 IF array_upper(isin, 1) IS NOT NULL THEN
1757 FOR i IN 1..array_upper(isin, 1) LOOP
1758 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1759 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1760 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1761 isin_tokens := isin_tokens || address_street_word_id;
1764 -- merge into address vector
1765 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1766 IF address_street_word_id IS NOT NULL THEN
1767 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1773 -- for the USA we have an additional address table. Merge in zip codes from there too
1774 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1775 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1776 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1777 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1778 isin_tokens := isin_tokens || address_street_word_id;
1780 -- also merge in the single word version
1781 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1782 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1786 -- RAISE WARNING 'ISIN: %', isin_tokens;
1788 -- Process area matches
1789 location_rank_search := 0;
1790 location_distance := 0;
1791 location_parent := NULL;
1792 -- added ourself as address already
1793 address_havelevel[NEW.rank_address] := true;
1794 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1795 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1797 --RAISE WARNING ' AREA: %',location;
1799 IF location.rank_address != location_rank_search THEN
1800 location_rank_search := location.rank_address;
1801 location_distance := location.distance * 1.5;
1804 IF location.distance < location_distance OR NOT location.isguess THEN
1806 location_isaddress := NOT address_havelevel[location.rank_address];
1807 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1808 location_isaddress := ST_Contains(location_parent,location.centroid);
1811 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1812 -- Add it to the list of search terms
1813 IF location.rank_search > 4 THEN
1814 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1816 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1818 IF location_isaddress THEN
1820 address_havelevel[location.rank_address] := true;
1821 IF NOT location.isguess THEN
1822 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1825 IF location.rank_address > parent_place_id_rank THEN
1826 NEW.parent_place_id = location.place_id;
1827 parent_place_id_rank = location.rank_address;
1832 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1838 -- try using the isin value to find parent places
1839 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1840 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1841 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1842 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1844 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1846 --RAISE WARNING ' ISIN: %',location;
1848 IF location.rank_search > 4 THEN
1849 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1850 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1851 address_havelevel[location.rank_address] := true;
1853 IF location.rank_address > parent_place_id_rank THEN
1854 NEW.parent_place_id = location.place_id;
1855 parent_place_id_rank = location.rank_address;
1865 -- for long ways we should add search terms for the entire length
1866 IF st_length(NEW.geometry) > 0.05 THEN
1868 location_rank_search := 0;
1869 location_distance := 0;
1871 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1873 IF location.rank_address != location_rank_search THEN
1874 location_rank_search := location.rank_address;
1875 location_distance := location.distance * 1.5;
1878 IF location.rank_search > 4 AND location.distance < location_distance THEN
1880 -- Add it to the list of search terms
1881 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1882 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1890 -- if we have a name add this to the name search table
1891 IF NEW.name IS NOT NULL THEN
1893 IF NEW.rank_search <= 25 THEN
1894 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1897 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1898 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1901 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);
1905 -- If we've not managed to pick up a better one - default centroid
1906 IF NEW.centroid IS NULL THEN
1907 NEW.centroid := place_centroid;
1917 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1923 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1925 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1926 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1927 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1928 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1930 IF OLD.rank_address < 30 THEN
1932 -- mark everything linked to this place for re-indexing
1933 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1934 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1935 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1937 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1938 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1940 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1941 b := deleteRoad(OLD.partition, OLD.place_id);
1943 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1944 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1945 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1949 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1951 IF OLD.rank_address < 26 THEN
1952 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1955 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1957 IF OLD.name is not null THEN
1958 b := deleteSearchName(OLD.partition, OLD.place_id);
1961 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1963 DELETE FROM place_addressline where place_id = OLD.place_id;
1965 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1967 -- remove from tables for special search
1968 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1969 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1971 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1974 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1982 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1988 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1990 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1991 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1992 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;
1994 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2000 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;
2008 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2013 existingplacex RECORD;
2014 existinggeometry GEOMETRY;
2015 existingplace_id BIGINT;
2020 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2021 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2023 IF FALSE and NEW.osm_type = 'R' THEN
2024 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;
2025 --DEBUG: RAISE WARNING '%', existingplacex;
2028 -- remove operator tag for most places, messes too much with search_name indexes
2029 IF NEW.class not in ('amenity', 'shop') THEN
2030 NEW.name := delete(NEW.name, 'operator');
2033 -- Just block these - lots and pointless
2034 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
2035 -- if the name tag was removed, older versions might still be lurking in the place table
2036 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2040 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
2041 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
2042 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2043 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2047 -- Patch in additional country names
2048 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
2049 select coalesce(country_name.name || NEW.name,NEW.name) from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
2052 -- Have we already done this place?
2053 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;
2055 -- Get the existing place_id
2056 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;
2058 -- Handle a place changing type by removing the old data
2059 -- My generated 'place' types are causing havok because they overlap with real keys
2060 -- TODO: move them to their own special purpose key/class to avoid collisions
2061 IF existing.osm_type IS NULL THEN
2062 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2065 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2066 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2069 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2070 AND st_area(existing.geometry) > 0.02
2071 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2072 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2074 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2075 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2079 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2080 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2082 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2083 IF existingplacex.osm_type IS NULL OR
2084 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2087 IF existingplacex.osm_type IS NOT NULL THEN
2088 -- sanity check: ignore admin_level changes on places with too many active children
2089 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2090 --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;
2091 --LIMIT INDEXING: IF i > 100000 THEN
2092 --LIMIT INDEXING: RETURN null;
2093 --LIMIT INDEXING: END IF;
2096 IF existing.osm_type IS NOT NULL THEN
2097 -- pathological case caused by the triggerless copy into place during initial import
2098 -- force delete even for large areas, it will be reinserted later
2099 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;
2100 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2103 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2104 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2105 street, addr_place, isin, postcode, country_code, extratags, geometry)
2106 values (NEW.osm_type
2122 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2127 -- Various ways to do the update
2129 -- Debug, what's changed?
2131 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2132 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2134 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2135 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2137 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2138 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2140 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2141 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2143 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2144 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2146 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2147 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2149 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2150 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2154 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2155 IF existing.geometry::text != NEW.geometry::text
2156 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2157 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2160 -- Get the version of the geometry actually used (in placex table)
2161 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;
2163 -- Performance limit
2164 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2166 -- 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
2167 update placex set indexed_status = 2 where indexed_status = 0 and
2168 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2169 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2170 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2172 update placex set indexed_status = 2 where indexed_status = 0 and
2173 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2174 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2175 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2181 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
2182 IF FALSE AND existingplacex.rank_search < 26
2183 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
2184 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
2185 AND coalesce(existing.addr_place, '') = coalesce(NEW.addr_place, '')
2186 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
2187 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
2188 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
2189 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2192 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
2194 IF st_area(NEW.geometry) < 0.5 THEN
2195 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2196 and placex.place_id = place_addressline.place_id and indexed_status = 0
2197 and (rank_search < 28 or name is not null);
2204 -- Anything else has changed - reindex the lot
2205 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2206 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2207 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2208 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2209 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2210 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2211 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2213 -- performance, can't take the load of re-indexing a whole country / huge area
2214 IF st_area(NEW.geometry) < 0.5 THEN
2215 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
2216 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
2223 -- refuse to update multiplpoygons with too many objects, too much of a performance hit
2224 IF ST_NumGeometries(NEW.geometry) > 2000 THEN
2225 RAISE WARNING 'Dropping update of % % because of geometry complexity.', NEW.osm_type, NEW.osm_id;
2229 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2230 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2231 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2232 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2233 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2234 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2235 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2236 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2237 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2238 OR existing.geometry::text != NEW.geometry::text
2243 housenumber = NEW.housenumber,
2244 street = NEW.street,
2245 addr_place = NEW.addr_place,
2247 postcode = NEW.postcode,
2248 country_code = NEW.country_code,
2249 extratags = NEW.extratags,
2250 admin_level = NEW.admin_level,
2251 geometry = NEW.geometry
2252 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2254 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2255 IF NEW.postcode IS NULL THEN
2256 -- postcode was deleted, no longer retain in placex
2257 DELETE FROM placex where place_id = existingplacex.place_id;
2261 NEW.name := hstore('ref', NEW.postcode);
2266 housenumber = NEW.housenumber,
2267 street = NEW.street,
2268 addr_place = NEW.addr_place,
2270 postcode = NEW.postcode,
2271 country_code = NEW.country_code,
2272 parent_place_id = null,
2273 extratags = NEW.extratags,
2274 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2276 geometry = NEW.geometry
2277 where place_id = existingplacex.place_id;
2281 -- Abort the add (we modified the existing place instead)
2285 $$ LANGUAGE plpgsql;
2287 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2294 IF name is null THEN
2298 search := languagepref;
2300 FOR j IN 1..array_upper(search, 1) LOOP
2301 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2302 return trim(name->search[j]);
2306 -- anything will do as a fallback - just take the first name type thing there is
2307 search := avals(name);
2311 LANGUAGE plpgsql IMMUTABLE;
2314 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2325 search := ARRAY['ref'];
2328 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2331 select rank_address,name,distance,length(name::text) as namelength
2332 from place_addressline join placex on (address_place_id = placex.place_id)
2333 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2334 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2336 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2337 FOR j IN 1..array_upper(search, 1) LOOP
2338 FOR k IN 1..array_upper(location.name, 1) LOOP
2339 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
2340 result[(100 - location.rank_address)] := trim(location.name[k].value);
2341 found := location.rank_address;
2348 RETURN array_to_string(result,', ');
2353 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2365 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2366 currresult := trim(get_name_by_language(location.name, languagepref));
2367 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2368 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2369 prevresult := currresult;
2373 RETURN array_to_string(result,', ');
2378 DROP TYPE IF EXISTS addressline CASCADE;
2379 create type addressline as (
2386 admin_level INTEGER,
2389 rank_address INTEGER,
2393 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2396 for_place_id BIGINT;
2401 countrylocation RECORD;
2402 searchcountrycode varchar(2);
2403 searchhousenumber TEXT;
2404 searchhousename HSTORE;
2405 searchrankaddress INTEGER;
2406 searchpostcode TEXT;
2413 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2414 WHERE place_id = in_place_id
2415 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2417 IF for_place_id IS NULL THEN
2418 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2419 WHERE place_id = in_place_id
2420 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2423 IF for_place_id IS NULL THEN
2424 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2425 WHERE place_id = in_place_id and rank_address = 30
2426 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2429 IF for_place_id IS NULL THEN
2430 for_place_id := in_place_id;
2431 select calculated_country_code, housenumber, rank_search, postcode, null from placex where place_id = for_place_id
2432 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2435 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2438 hadcountry := false;
2440 select placex.place_id, osm_type, osm_id,
2441 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2442 class, type, admin_level, true as fromarea, true as isaddress,
2443 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2444 0 as distance, calculated_country_code, postcode
2446 where place_id = for_place_id
2448 --RAISE WARNING '%',location;
2449 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2450 searchcountrycode := location.calculated_country_code;
2452 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2453 location.isaddress := FALSE;
2455 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2456 searchpostcode := location.postcode;
2458 IF location.rank_address = 4 AND location.isaddress THEN
2461 IF location.rank_address < 4 AND NOT hadcountry THEN
2462 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2463 IF countryname IS NOT NULL THEN
2464 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2465 RETURN NEXT countrylocation;
2468 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2469 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2470 location.distance)::addressline;
2471 RETURN NEXT countrylocation;
2472 found := location.rank_address;
2476 select placex.place_id, osm_type, osm_id,
2477 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2478 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2479 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2480 admin_level, fromarea, isaddress,
2481 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,
2482 distance,calculated_country_code,postcode
2483 from place_addressline join placex on (address_place_id = placex.place_id)
2484 where place_addressline.place_id = for_place_id
2485 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2486 and address_place_id != for_place_id
2487 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2488 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2490 --RAISE WARNING '%',location;
2491 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2492 searchcountrycode := location.calculated_country_code;
2494 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2495 location.isaddress := FALSE;
2497 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2498 searchpostcode := location.postcode;
2500 IF location.rank_address = 4 AND location.isaddress THEN
2503 IF location.rank_address < 4 AND NOT hadcountry THEN
2504 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2505 IF countryname IS NOT NULL THEN
2506 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2507 RETURN NEXT countrylocation;
2510 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2511 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2512 location.distance)::addressline;
2513 RETURN NEXT countrylocation;
2514 found := location.rank_address;
2518 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2519 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2520 IF countryname IS NOT NULL THEN
2521 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2522 RETURN NEXT location;
2526 IF searchcountrycode IS NOT NULL THEN
2527 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2528 RETURN NEXT location;
2531 IF searchhousename IS NOT NULL THEN
2532 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2533 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2534 RETURN NEXT location;
2537 IF searchhousenumber IS NOT NULL THEN
2538 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2539 RETURN NEXT location;
2542 IF searchpostcode IS NOT NULL THEN
2543 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2544 RETURN NEXT location;
2553 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2556 numfeatures integer;
2560 housenumber = place.housenumber,
2561 street = place.street,
2562 addr_place = place.addr_place,
2564 postcode = place.postcode,
2565 country_code = place.country_code,
2566 parent_place_id = null
2568 where placex.place_id = search_place_id
2569 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2570 and place.class = placex.class and place.type = placex.type;
2571 update placex set indexed_status = 2 where place_id = search_place_id;
2572 update placex set indexed_status = 0 where place_id = search_place_id;
2578 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2584 ELSEIF rank < 4 THEN
2586 ELSEIF rank < 8 THEN
2588 ELSEIF rank < 12 THEN
2590 ELSEIF rank < 16 THEN
2592 ELSEIF rank = 16 THEN
2594 ELSEIF rank = 17 THEN
2595 RETURN 'Town / Island';
2596 ELSEIF rank = 18 THEN
2597 RETURN 'Village / Hamlet';
2598 ELSEIF rank = 20 THEN
2600 ELSEIF rank = 21 THEN
2601 RETURN 'Postcode Area';
2602 ELSEIF rank = 22 THEN
2603 RETURN 'Croft / Farm / Locality / Islet';
2604 ELSEIF rank = 23 THEN
2605 RETURN 'Postcode Area';
2606 ELSEIF rank = 25 THEN
2607 RETURN 'Postcode Point';
2608 ELSEIF rank = 26 THEN
2609 RETURN 'Street / Major Landmark';
2610 ELSEIF rank = 27 THEN
2611 RETURN 'Minory Street / Path';
2612 ELSEIF rank = 28 THEN
2613 RETURN 'House / Building';
2615 RETURN 'Other: '||rank;
2622 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2628 ELSEIF rank < 2 THEN
2630 ELSEIF rank < 4 THEN
2632 ELSEIF rank = 5 THEN
2634 ELSEIF rank < 8 THEN
2636 ELSEIF rank < 12 THEN
2638 ELSEIF rank < 16 THEN
2640 ELSEIF rank = 16 THEN
2642 ELSEIF rank = 17 THEN
2643 RETURN 'Town / Village / Hamlet';
2644 ELSEIF rank = 20 THEN
2646 ELSEIF rank = 21 THEN
2647 RETURN 'Postcode Area';
2648 ELSEIF rank = 22 THEN
2649 RETURN 'Croft / Farm / Locality / Islet';
2650 ELSEIF rank = 23 THEN
2651 RETURN 'Postcode Area';
2652 ELSEIF rank = 25 THEN
2653 RETURN 'Postcode Point';
2654 ELSEIF rank = 26 THEN
2655 RETURN 'Street / Major Landmark';
2656 ELSEIF rank = 27 THEN
2657 RETURN 'Minory Street / Path';
2658 ELSEIF rank = 28 THEN
2659 RETURN 'House / Building';
2661 RETURN 'Other: '||rank;
2668 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2675 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2676 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2683 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2691 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2693 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2694 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2696 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2704 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2705 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2710 place_centroid GEOMETRY;
2711 out_partition INTEGER;
2712 out_parent_place_id BIGINT;
2714 address_street_word_id INTEGER;
2719 place_centroid := ST_Centroid(pointgeo);
2720 out_partition := get_partition(in_countrycode);
2721 out_parent_place_id := null;
2723 address_street_word_id := get_name_id(make_standard_name(in_street));
2724 IF address_street_word_id IS NOT NULL THEN
2725 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2726 out_parent_place_id := location.place_id;
2730 IF out_parent_place_id IS NULL THEN
2731 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2732 out_parent_place_id := location.place_id;
2736 out_postcode := in_postcode;
2737 IF out_postcode IS NULL THEN
2738 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2740 IF out_postcode IS NULL THEN
2741 out_postcode := getNearestPostcode(out_partition, place_centroid);
2745 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2746 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2747 newpoints := newpoints + 1;
2754 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2761 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2762 IF members[i+1] = member THEN
2763 result := result || members[i];
2772 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2778 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2779 IF members[i+1] = ANY(memberLabels) THEN
2780 RETURN NEXT members[i];
2789 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2790 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2792 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2793 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
2794 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2795 ), '') AS bytea), 'UTF8');
2797 LANGUAGE SQL IMMUTABLE STRICT;
2799 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2803 RETURN decode_url_part(p);
2805 WHEN others THEN return null;
2808 LANGUAGE plpgsql IMMUTABLE;
2810 DROP TYPE wikipedia_article_match CASCADE;
2811 create type wikipedia_article_match as (
2817 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2823 wiki_article_title TEXT;
2824 wiki_article_language TEXT;
2825 result wikipedia_article_match;
2827 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'];
2829 WHILE langs[i] IS NOT NULL LOOP
2830 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2831 IF wiki_article is not null THEN
2832 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2833 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2834 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2835 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2836 wiki_article := replace(wiki_article,' ','_');
2837 IF strpos(wiki_article, ':') IN (3,4) THEN
2838 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2839 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2841 wiki_article_title := trim(wiki_article);
2842 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;
2845 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2846 from wikipedia_article
2847 where language = wiki_article_language and
2848 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2850 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2851 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2852 where wikipedia_redirect.language = wiki_article_language and
2853 (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'\\',''))
2854 order by importance desc limit 1 INTO result;
2856 IF result.language is not null THEN
2867 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2868 RETURNS SETOF GEOMETRY
2882 remainingdepth INTEGER;
2887 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2889 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2890 RETURN NEXT geometry;
2894 remainingdepth := maxdepth - 1;
2895 area := ST_AREA(geometry);
2896 IF remainingdepth < 1 OR area < maxarea THEN
2897 RETURN NEXT geometry;
2901 xmin := st_xmin(geometry);
2902 xmax := st_xmax(geometry);
2903 ymin := st_ymin(geometry);
2904 ymax := st_ymax(geometry);
2905 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2907 -- if the geometry completely covers the box don't bother to slice any more
2908 IF ST_AREA(secbox) = area THEN
2909 RETURN NEXT geometry;
2913 xmid := (xmin+xmax)/2;
2914 ymid := (ymin+ymax)/2;
2917 FOR seg IN 1..4 LOOP
2920 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2923 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2926 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2929 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2932 IF st_intersects(geometry, secbox) THEN
2933 secgeo := st_intersection(geometry, secbox);
2934 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2935 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2936 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2938 RETURN NEXT geo.geom;
2950 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2951 RETURNS SETOF GEOMETRY
2956 -- 10000000000 is ~~ 1x1 degree
2957 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2958 RETURN NEXT geo.geom;
2966 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2970 osmtype character(1);
2974 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2975 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2976 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2977 -- force delete from place/placex by making it a very small geometry
2978 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;
2979 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2986 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2994 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2995 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2996 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2997 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2998 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2999 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3000 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));
3001 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
3002 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));
3008 ELSEIF rank < 18 THEN
3010 ELSEIF rank < 20 THEN
3012 ELSEIF rank = 21 THEN
3014 ELSEIF rank < 24 THEN
3016 ELSEIF rank < 26 THEN
3017 diameter := 0.002; -- 100 to 200 meters
3018 ELSEIF rank < 28 THEN
3019 diameter := 0.001; -- 50 to 100 meters
3021 IF diameter > 0 THEN
3023 -- roads may cause reparenting for >27 rank places
3024 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
3025 ELSEIF rank >= 16 THEN
3026 -- up to rank 16, street-less addresses may need reparenting
3027 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);
3029 -- for all other places the search terms may change as well
3030 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);