1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 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;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
91 return_word_id INTEGER;
93 lookup_token := ' '||trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 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;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
145 nospace_lookup_token TEXT;
146 return_word_id INTEGER;
148 lookup_token := ' '||trim(lookup_word);
149 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
150 IF return_word_id IS NULL THEN
151 return_word_id := nextval('seq_word');
152 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
153 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
154 -- IF ' '||nospace_lookup_token != lookup_token THEN
155 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
168 RETURN getorcreate_name_id(lookup_word, '');
173 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
178 return_word_id INTEGER;
180 lookup_token := trim(lookup_word);
181 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
182 RETURN return_word_id;
185 LANGUAGE plpgsql IMMUTABLE;
187 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
192 return_word_id INTEGER;
194 lookup_token := ' '||trim(lookup_word);
195 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
196 RETURN return_word_id;
199 LANGUAGE plpgsql IMMUTABLE;
201 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
206 return_word_ids INTEGER[];
208 lookup_token := ' '||trim(lookup_word);
209 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
210 RETURN return_word_ids;
213 LANGUAGE plpgsql IMMUTABLE;
215 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
222 IF array_upper(a, 1) IS NULL THEN
225 IF array_upper(b, 1) IS NULL THEN
229 FOR i IN 1..array_upper(b, 1) LOOP
230 IF NOT (ARRAY[b[i]] <@ r) THEN
237 LANGUAGE plpgsql IMMUTABLE;
239 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
248 FOR item IN SELECT (each(src)).* LOOP
250 s := make_standard_name(item.value);
251 w := getorcreate_country(s, lookup_country_code);
253 words := regexp_split_to_array(item.value, E'[,;()]');
254 IF array_upper(words, 1) != 1 THEN
255 FOR j IN 1..array_upper(words, 1) LOOP
256 s := make_standard_name(words[j]);
258 w := getorcreate_country(s, lookup_country_code);
267 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
277 result := '{}'::INTEGER[];
279 FOR item IN SELECT (each(src)).* LOOP
281 s := make_standard_name(item.value);
283 w := getorcreate_name_id(s, item.value);
285 IF not(ARRAY[w] <@ result) THEN
286 result := result || w;
289 w := getorcreate_word_id(s);
291 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
292 result := result || w;
295 words := string_to_array(s, ' ');
296 IF array_upper(words, 1) IS NOT NULL THEN
297 FOR j IN 1..array_upper(words, 1) LOOP
298 IF (words[j] != '') THEN
299 w = getorcreate_word_id(words[j]);
300 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
301 result := result || w;
307 words := regexp_split_to_array(item.value, E'[,;()]');
308 IF array_upper(words, 1) != 1 THEN
309 FOR j IN 1..array_upper(words, 1) LOOP
310 s := make_standard_name(words[j]);
312 w := getorcreate_word_id(s);
313 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
314 result := result || w;
320 s := regexp_replace(item.value, '市$', '');
321 IF s != item.value THEN
322 s := make_standard_name(s);
324 w := getorcreate_name_id(s, item.value);
325 IF NOT (ARRAY[w] <@ result) THEN
326 result := result || w;
336 LANGUAGE plpgsql IMMUTABLE;
338 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
348 result := '{}'::INTEGER[];
350 s := make_standard_name(src);
351 w := getorcreate_name_id(s, src);
353 IF NOT (ARRAY[w] <@ result) THEN
354 result := result || w;
357 w := getorcreate_word_id(s);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
363 words := string_to_array(s, ' ');
364 IF array_upper(words, 1) IS NOT NULL THEN
365 FOR j IN 1..array_upper(words, 1) LOOP
366 IF (words[j] != '') THEN
367 w = getorcreate_word_id(words[j]);
368 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
369 result := result || w;
375 words := regexp_split_to_array(src, E'[,;()]');
376 IF array_upper(words, 1) != 1 THEN
377 FOR j IN 1..array_upper(words, 1) LOOP
378 s := make_standard_name(words[j]);
380 w := getorcreate_word_id(s);
381 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
382 result := result || w;
388 s := regexp_replace(src, '市$', '');
390 s := make_standard_name(s);
392 w := getorcreate_name_id(s, src);
393 IF NOT (ARRAY[w] <@ result) THEN
394 result := result || w;
402 LANGUAGE plpgsql IMMUTABLE;
404 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
407 place_centre GEOMETRY;
410 place_centre := ST_PointOnSurface(place);
412 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
414 -- Try for a OSM polygon
415 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
417 RETURN nearcountry.country_code;
420 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
422 -- Try for OSM fallback data
423 -- The order is to deal with places like HongKong that are 'states' within another polygon
424 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
426 RETURN nearcountry.country_code;
429 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
431 -- Natural earth data
432 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
434 RETURN nearcountry.country_code;
437 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
440 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
442 RETURN nearcountry.country_code;
445 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
447 -- Natural earth data
448 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
450 RETURN nearcountry.country_code;
456 LANGUAGE plpgsql IMMUTABLE;
458 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
463 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
465 RETURN lower(nearcountry.country_default_language_code);
470 LANGUAGE plpgsql IMMUTABLE;
472 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
477 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
479 RETURN lower(nearcountry.country_default_language_codes);
484 LANGUAGE plpgsql IMMUTABLE;
486 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
491 FOR nearcountry IN select partition from country_name where country_code = in_country_code
493 RETURN nearcountry.partition;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
504 DELETE FROM location_area where place_id = OLD_place_id;
505 -- TODO:location_area
511 CREATE OR REPLACE FUNCTION add_location(
513 country_code varchar(2),
517 rank_address INTEGER,
532 IF rank_search > 25 THEN
533 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
536 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
538 x := deleteLocationArea(partition, place_id, rank_search);
541 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
544 centroid := ST_Centroid(geometry);
546 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
547 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
553 IF rank_address = 0 THEN
555 ELSEIF rank_search <= 14 THEN
557 ELSEIF rank_search <= 15 THEN
559 ELSEIF rank_search <= 16 THEN
561 ELSEIF rank_search <= 17 THEN
563 ELSEIF rank_search <= 21 THEN
565 ELSEIF rank_search = 25 THEN
569 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
571 secgeo := ST_Buffer(geometry, diameter);
572 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
582 -- find the parent road of the cut road parts
583 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
584 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
589 parent_place_id BIGINT;
590 address_street_word_ids INTEGER[];
596 addr_street = street;
599 IF addr_street is null and addr_place is null THEN
600 select nodes from planet_osm_ways where id = wayid INTO waynodes;
601 FOR location IN SELECT placex.street, placex.addr_place from placex
602 where osm_type = 'N' and osm_id = ANY(waynodes)
603 and (placex.street is not null or placex.addr_place is not null)
604 and indexed_status < 100
606 addr_street = location.street;
607 addr_place = location.addr_place;
611 IF addr_street IS NOT NULL THEN
612 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
613 IF address_street_word_ids IS NOT NULL THEN
614 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
615 parent_place_id := location.place_id;
620 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
621 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
622 IF address_street_word_ids IS NOT NULL THEN
623 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
624 parent_place_id := location.place_id;
629 IF parent_place_id is null THEN
630 FOR location IN SELECT place_id FROM placex
631 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
632 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
633 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
636 parent_place_id := location.place_id;
640 IF parent_place_id is null THEN
644 RETURN parent_place_id;
650 CREATE OR REPLACE FUNCTION insert_osmline(wayid BIGINT, interpolationtype TEXT,
651 street TEXT, addr_place TEXT,
652 defpostalcode TEXT, country_code TEXT,
654 RETURNS INTEGER AS $$
669 place_centroid GEOMETRY;
670 calculated_country_code VARCHAR(2);
672 geometry_sector INTEGER;
675 place_centroid := ST_PointOnSurface(geom);
676 calculated_country_code := lower(get_country_code(place_centroid));
677 partition := get_partition(calculated_country_code);
678 geometry_sector := geometry_sector(partition, place_centroid);
680 IF interpolationtype != 'odd' AND interpolationtype != 'even' AND interpolationtype!='all' THEN
681 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
685 select nodes from planet_osm_ways where id = wayid INTO waynodes;
687 IF array_upper(waynodes, 1) IS NULL THEN
694 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
696 select * from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
697 and housenumber is not NULL limit 1 INTO nextnode;
698 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
699 IF nextnode.osm_id IS NOT NULL THEN
700 --RAISE NOTICE 'place_id is not null';
701 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
702 -- Make sure that the point is actually on the line. That might
703 -- be a bit paranoid but ensures that the algorithm still works
704 -- should osm2pgsql attempt to repair geometries.
705 splitline := split_line_on_node(linegeo, nextnode.geometry);
706 sectiongeo := ST_GeometryN(splitline, 1);
707 linegeo := ST_GeometryN(splitline, 2);
709 sectiongeo = linegeo;
711 endnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
713 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
714 AND startnumber != endnumber
715 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
717 IF (startnumber > endnumber) THEN
718 housenum := endnumber;
719 endnumber := startnumber;
720 startnumber := housenum;
721 sectiongeo := ST_Reverse(sectiongeo);
724 insert into location_property_osmline
725 values (sectiongeo, nextval('seq_place'), partition, wayid, NULL,
726 startnumber, endnumber, interpolationtype,
727 coalesce(street, prevnode.street, nextnode.street),
728 coalesce(addr_place, prevnode.addr_place, nextnode.addr_place),
729 coalesce(defpostalcode, prevnode.postcode, nextnode.postcode),
730 calculated_country_code, geometry_sector, 2, now());
733 -- early break if we are out of line string,
734 -- might happen when a line string loops back on itself
735 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
739 startnumber := substring(nextnode.housenumber,'[0-9]+')::integer;
740 prevnode := nextnode;
750 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
756 country_code VARCHAR(2);
757 default_language VARCHAR(10);
762 --DEBUG: RAISE WARNING '% %',NEW.osm_type,NEW.osm_id;
764 -- ignore interpolated addresses, not necessary anymore, cause interpolated addresses are now in location_property_osmline
765 IF NEW.class = 'place' and NEW.type = 'address' THEN
769 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
770 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
771 RAISE WARNING 'invalid geometry %',NEW.osm_id;
775 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
777 NEW.place_id := nextval('seq_place');
778 NEW.indexed_status := 1; --STATUS_NEW
780 NEW.calculated_country_code := lower(get_country_code(NEW.geometry));
782 NEW.partition := get_partition(NEW.calculated_country_code);
783 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
785 -- copy 'name' to or from the default language (if there is a default language)
786 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
787 default_language := get_country_language_code(NEW.calculated_country_code);
788 IF default_language IS NOT NULL THEN
789 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
790 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
791 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
792 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
797 IF NEW.admin_level > 15 THEN
798 NEW.admin_level := 15;
801 IF NEW.housenumber IS NOT NULL THEN
802 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
805 IF NEW.osm_type = 'X' THEN
806 -- E'X'ternal records should already be in the right format so do nothing
808 NEW.rank_search := 30;
809 NEW.rank_address := NEW.rank_search;
811 -- By doing in postgres we have the country available to us - currently only used for postcode
812 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
814 IF NEW.postcode IS NULL THEN
815 -- most likely just a part of a multipolygon postcode boundary, throw it away
819 NEW.name := hstore('ref', NEW.postcode);
821 IF NEW.calculated_country_code = 'gb' THEN
823 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
824 NEW.rank_search := 25;
825 NEW.rank_address := 5;
826 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
827 NEW.rank_search := 23;
828 NEW.rank_address := 5;
829 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
830 NEW.rank_search := 21;
831 NEW.rank_address := 5;
834 ELSEIF NEW.calculated_country_code = 'sg' THEN
836 IF NEW.postcode ~ '^([0-9]{6})$' THEN
837 NEW.rank_search := 25;
838 NEW.rank_address := 11;
841 ELSEIF NEW.calculated_country_code = 'de' THEN
843 IF NEW.postcode ~ '^([0-9]{5})$' THEN
844 NEW.rank_search := 21;
845 NEW.rank_address := 11;
849 -- Guess at the postcode format and coverage (!)
850 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
851 NEW.rank_search := 21;
852 NEW.rank_address := 11;
854 -- Does it look splitable into and area and local code?
855 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
857 IF postcode IS NOT NULL THEN
858 NEW.rank_search := 25;
859 NEW.rank_address := 11;
860 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
861 NEW.rank_search := 21;
862 NEW.rank_address := 11;
867 ELSEIF NEW.class = 'place' THEN
868 IF NEW.type in ('continent') THEN
869 NEW.rank_search := 2;
870 NEW.rank_address := NEW.rank_search;
871 NEW.calculated_country_code := NULL;
872 ELSEIF NEW.type in ('sea') THEN
873 NEW.rank_search := 2;
874 NEW.rank_address := 0;
875 NEW.calculated_country_code := NULL;
876 ELSEIF NEW.type in ('country') THEN
877 NEW.rank_search := 4;
878 NEW.rank_address := NEW.rank_search;
879 ELSEIF NEW.type in ('state') THEN
880 NEW.rank_search := 8;
881 NEW.rank_address := NEW.rank_search;
882 ELSEIF NEW.type in ('region') THEN
883 NEW.rank_search := 18; -- dropped from previous value of 10
884 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
885 ELSEIF NEW.type in ('county') THEN
886 NEW.rank_search := 12;
887 NEW.rank_address := NEW.rank_search;
888 ELSEIF NEW.type in ('city') THEN
889 NEW.rank_search := 16;
890 NEW.rank_address := NEW.rank_search;
891 ELSEIF NEW.type in ('island') THEN
892 NEW.rank_search := 17;
893 NEW.rank_address := 0;
894 ELSEIF NEW.type in ('town') THEN
895 NEW.rank_search := 18;
896 NEW.rank_address := 16;
897 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
898 NEW.rank_search := 19;
899 NEW.rank_address := 16;
900 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
901 NEW.rank_search := 20;
902 NEW.rank_address := NEW.rank_search;
903 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
904 NEW.rank_search := 20;
905 NEW.rank_address := 0;
906 -- Irish townlands, tagged as place=locality and locality=townland
907 IF (NEW.extratags -> 'locality') = 'townland' THEN
908 NEW.rank_address := 20;
910 ELSEIF NEW.type in ('neighbourhood') THEN
911 NEW.rank_search := 22;
912 NEW.rank_address := 22;
913 ELSEIF NEW.type in ('house','building') THEN
914 NEW.rank_search := 30;
915 NEW.rank_address := NEW.rank_search;
916 ELSEIF NEW.type in ('houses') THEN
917 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
918 NEW.rank_search := 28;
919 NEW.rank_address := 0;
922 ELSEIF NEW.class = 'boundary' THEN
923 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
924 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
927 NEW.rank_search := NEW.admin_level * 2;
928 IF NEW.type = 'administrative' THEN
929 NEW.rank_address := NEW.rank_search;
931 NEW.rank_address := 0;
933 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
934 NEW.rank_search := 22;
935 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
936 NEW.rank_address := NEW.rank_search;
938 NEW.rank_address := 0;
940 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
941 NEW.rank_search := 18;
942 NEW.rank_address := 0;
943 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
944 NEW.rank_search := 4;
945 NEW.rank_address := NEW.rank_search;
946 -- any feature more than 5 square miles is probably worth indexing
947 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
948 NEW.rank_search := 22;
949 NEW.rank_address := 0;
950 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
952 ELSEIF NEW.class = 'waterway' THEN
953 IF NEW.osm_type = 'R' THEN
954 NEW.rank_search := 16;
956 NEW.rank_search := 17;
958 NEW.rank_address := 0;
959 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
960 NEW.rank_search := 27;
961 NEW.rank_address := NEW.rank_search;
962 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
963 NEW.rank_search := 26;
964 NEW.rank_address := NEW.rank_search;
965 ELSEIF NEW.class = 'mountain_pass' THEN
966 NEW.rank_search := 20;
967 NEW.rank_address := 0;
972 IF NEW.rank_search > 30 THEN
973 NEW.rank_search := 30;
976 IF NEW.rank_address > 30 THEN
977 NEW.rank_address := 30;
980 IF (NEW.extratags -> 'capital') = 'yes' THEN
981 NEW.rank_search := NEW.rank_search - 1;
984 -- a country code make no sense below rank 4 (country)
985 IF NEW.rank_search < 4 THEN
986 NEW.calculated_country_code := NULL;
989 -- Block import below rank 22
990 -- IF NEW.rank_search > 22 THEN
994 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
996 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
998 IF NEW.rank_address > 0 THEN
999 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1000 -- Performance: We just can't handle re-indexing for country level changes
1001 IF st_area(NEW.geometry) < 1 THEN
1002 -- mark items within the geometry for re-indexing
1003 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1005 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1006 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1007 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));
1008 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1009 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));
1012 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1014 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1015 IF NEW.type='postcode' THEN
1017 ELSEIF NEW.rank_search < 16 THEN
1019 ELSEIF NEW.rank_search < 18 THEN
1021 ELSEIF NEW.rank_search < 20 THEN
1023 ELSEIF NEW.rank_search = 21 THEN
1025 ELSEIF NEW.rank_search < 24 THEN
1027 ELSEIF NEW.rank_search < 26 THEN
1028 diameter := 0.002; -- 100 to 200 meters
1029 ELSEIF NEW.rank_search < 28 THEN
1030 diameter := 0.001; -- 50 to 100 meters
1032 IF diameter > 0 THEN
1033 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1034 IF NEW.rank_search >= 26 THEN
1035 -- roads may cause reparenting for >27 rank places
1036 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1037 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1038 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1039 ELSEIF NEW.rank_search >= 16 THEN
1040 -- up to rank 16, street-less addresses may need reparenting
1041 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);
1043 -- for all other places the search terms may change as well
1044 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);
1051 -- add to tables for special search
1052 -- Note: won't work on initial import because the classtype tables
1053 -- do not yet exist. It won't hurt either.
1054 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1055 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1057 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1058 USING NEW.place_id, ST_Centroid(NEW.geometry);
1067 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1071 place_centroid GEOMETRY;
1074 IF OLD.indexed_status = 100 THEN
1075 delete from location_property_osmline where place_id = OLD.place_id;
1079 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1083 -- do the reparenting: (finally here, because ALL places in placex, that are needed for reparenting, need to be up to date)
1084 -- (the osm interpolationline in location_property_osmline was marked for reparenting in placex_insert/placex_delete with index_status = 1 or 2 (1 inset, 2 delete)
1085 -- => index.c: sets index_status back to 0
1086 -- => triggers this function)
1087 place_centroid := ST_PointOnSurface(NEW.linegeo);
1088 -- marking descendants for reparenting is not needed, because there are actually no descendants for interpolation lines
1089 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.street, NEW.addr_place,
1090 NEW.partition, place_centroid, NEW.linegeo);
1096 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1101 place_centroid GEOMETRY;
1103 search_maxdistance FLOAT[];
1104 search_mindistance FLOAT[];
1105 address_havelevel BOOLEAN[];
1112 relation_members TEXT[];
1114 linkedplacex RECORD;
1115 search_diameter FLOAT;
1116 search_prevdiameter FLOAT;
1117 search_maxrank INTEGER;
1118 address_maxrank INTEGER;
1119 address_street_word_id INTEGER;
1120 address_street_word_ids INTEGER[];
1121 parent_place_id_rank BIGINT;
1126 location_rank_search INTEGER;
1127 location_distance FLOAT;
1128 location_parent GEOMETRY;
1129 location_isaddress BOOLEAN;
1130 location_keywords INTEGER[];
1132 default_language TEXT;
1133 name_vector INTEGER[];
1134 nameaddress_vector INTEGER[];
1136 linked_node_id BIGINT;
1141 IF OLD.indexed_status = 100 THEN
1142 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1143 delete from placex where place_id = OLD.place_id;
1147 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1151 -- ignore interpolated addresses
1152 IF NEW.class = 'place' and NEW.type = 'address' THEN
1156 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1158 --RAISE WARNING '%',NEW.place_id;
1159 --RAISE WARNING '%', NEW;
1161 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1162 -- Silently do nothing
1166 NEW.indexed_date = now();
1168 result := deleteSearchName(NEW.partition, NEW.place_id);
1169 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1170 result := deleteRoad(NEW.partition, NEW.place_id);
1171 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1172 UPDATE placex set linked_place_id = null, indexed_status = 2
1173 where linked_place_id = NEW.place_id;
1174 -- update not necessary for osmline, cause linked_place_id does not exist
1176 IF NEW.linked_place_id is not null THEN
1180 -- Speed up searches - just use the centroid of the feature
1181 -- cheaper but less acurate
1182 place_centroid := ST_PointOnSurface(NEW.geometry);
1183 NEW.centroid := null;
1185 -- recalculate country and partition
1186 IF NEW.rank_search = 4 THEN
1187 -- for countries, believe the mapped country code,
1188 -- so that we remain in the right partition if the boundaries
1190 NEW.partition := get_partition(lower(NEW.country_code));
1191 IF NEW.partition = 0 THEN
1192 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1193 NEW.partition := get_partition(NEW.calculated_country_code);
1195 NEW.calculated_country_code := lower(NEW.country_code);
1198 IF NEW.rank_search > 4 THEN
1199 --NEW.calculated_country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1200 NEW.calculated_country_code := lower(get_country_code(place_centroid));
1202 NEW.calculated_country_code := NULL;
1204 NEW.partition := get_partition(NEW.calculated_country_code);
1207 -- waterway ways are linked when they are part of a relation and have the same class/type
1208 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1209 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1211 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1212 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1213 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1214 FOR linked_node_id IN SELECT place_id FROM placex
1215 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1216 and class = NEW.class and type = NEW.type
1217 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1219 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1226 -- Adding ourselves to the list simplifies address calculations later
1227 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1229 -- What level are we searching from
1230 search_maxrank := NEW.rank_search;
1232 -- Thought this wasn't needed but when we add new languages to the country_name table
1233 -- we need to update the existing names
1234 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1235 default_language := get_country_language_code(NEW.calculated_country_code);
1236 IF default_language IS NOT NULL THEN
1237 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1238 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1239 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1240 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1245 -- Initialise the name vector using our name
1246 name_vector := make_keywords(NEW.name);
1247 nameaddress_vector := '{}'::int[];
1250 address_havelevel[i] := false;
1253 NEW.importance := null;
1254 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1255 IF NEW.importance IS NULL THEN
1256 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;
1259 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1261 -- ---------------------------------------------------------------------------
1262 -- For low level elements we inherit from our parent road
1263 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1265 --RAISE WARNING 'finding street for %', NEW;
1267 -- We won't get a better centroid, besides these places are too small to care
1268 NEW.centroid := place_centroid;
1270 NEW.parent_place_id := null;
1272 -- if we have a POI and there is no address information,
1273 -- see if we can get it from a surrounding building
1274 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1275 AND NEW.housenumber IS NULL THEN
1276 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1277 and (housenumber is not null or street is not null or addr_place is not null)
1278 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1281 NEW.housenumber := location.housenumber;
1282 NEW.street := location.street;
1283 NEW.addr_place := location.addr_place;
1287 -- We have to find our parent road.
1288 -- Copy data from linked items (points on ways, addr:street links, relations)
1290 -- Is this object part of a relation?
1291 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1293 -- At the moment we only process one type of relation - associatedStreet
1294 IF relation.tags @> ARRAY['associatedStreet'] THEN
1295 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1296 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1297 --RAISE WARNING 'node in relation %',relation;
1298 SELECT place_id from placex where osm_type = 'W'
1299 and osm_id = substring(relation.members[i],2,200)::bigint
1300 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1307 -- Note that addr:street links can only be indexed once the street itself is indexed
1308 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1309 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1310 IF address_street_word_ids IS NOT NULL THEN
1311 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1312 NEW.parent_place_id := location.place_id;
1317 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1318 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1319 IF address_street_word_ids IS NOT NULL THEN
1320 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1321 NEW.parent_place_id := location.place_id;
1326 -- Is this node part of an interpolation?
1327 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1329 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1330 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1333 NEW.parent_place_id := location.parent_place_id;
1337 -- Is this node part of a way?
1338 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1340 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w
1341 where p.osm_type = 'W' and p.rank_search >= 26 and p.geometry && NEW.geometry and w.id = p.osm_id and NEW.osm_id = any(w.nodes)
1344 -- Way IS a road then we are on it - that must be our road
1345 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1346 --RAISE WARNING 'node in way that is a street %',location;
1347 NEW.parent_place_id := location.place_id;
1350 -- If the way mentions a street or place address, try that for parenting.
1351 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1352 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1353 IF address_street_word_ids IS NOT NULL THEN
1354 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1355 NEW.parent_place_id := linkedplacex.place_id;
1360 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1361 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1362 IF address_street_word_ids IS NOT NULL THEN
1363 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1364 NEW.parent_place_id := linkedplacex.place_id;
1369 -- Is the WAY part of a relation
1370 IF NEW.parent_place_id IS NULL THEN
1371 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1373 -- At the moment we only process one type of relation - associatedStreet
1374 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1375 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1376 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1377 --RAISE WARNING 'node in way that is in a relation %',relation;
1378 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1379 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1390 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1391 -- Still nothing, just use the nearest road
1392 IF NEW.parent_place_id IS NULL THEN
1393 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1394 NEW.parent_place_id := location.place_id;
1399 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1401 -- If we didn't find any road fallback to standard method
1402 IF NEW.parent_place_id IS NOT NULL THEN
1404 -- Get the details of the parent road
1405 select * from search_name where place_id = NEW.parent_place_id INTO location;
1406 NEW.calculated_country_code := location.country_code;
1408 -- Merge the postcode into the parent's address if necessary XXXX
1409 IF NEW.postcode IS NOT NULL THEN
1410 isin_tokens := '{}'::int[];
1411 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1412 IF address_street_word_id is not null
1413 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1414 isin_tokens := isin_tokens || address_street_word_id;
1416 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1417 IF address_street_word_id is not null
1418 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1419 isin_tokens := isin_tokens || address_street_word_id;
1421 IF isin_tokens != '{}'::int[] THEN
1423 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1424 WHERE place_id = NEW.parent_place_id;
1428 --RAISE WARNING '%', NEW.name;
1429 -- If there is no name it isn't searchable, don't bother to create a search record
1430 IF NEW.name is NULL THEN
1434 -- Merge address from parent
1435 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1436 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1438 -- Performance, it would be more acurate to do all the rest of the import
1439 -- process but it takes too long
1440 -- Just be happy with inheriting from parent road only
1442 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1443 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1446 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);
1453 -- RAISE WARNING ' INDEXING Started:';
1454 -- RAISE WARNING ' INDEXING: %',NEW;
1456 -- ---------------------------------------------------------------------------
1459 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1461 -- see if we have any special relation members
1462 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1464 -- RAISE WARNING 'get_osm_rel_members, label';
1465 IF relation_members IS NOT NULL THEN
1466 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1468 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1469 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1471 -- If we don't already have one use this as the centre point of the geometry
1472 IF NEW.centroid IS NULL THEN
1473 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1476 -- merge in the label name, re-init word vector
1477 IF NOT linkedPlacex.name IS NULL THEN
1478 NEW.name := linkedPlacex.name || NEW.name;
1479 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1482 -- merge in extra tags
1483 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1485 -- mark the linked place (excludes from search results)
1486 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1488 -- keep a note of the node id in case we need it for wikipedia in a bit
1489 linked_node_id := linkedPlacex.osm_id;
1494 IF NEW.centroid IS NULL THEN
1496 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1498 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1499 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1501 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1502 -- But that can be fixed by explicitly setting the label in the data
1503 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1504 AND NEW.rank_address = linkedPlacex.rank_address THEN
1506 -- If we don't already have one use this as the centre point of the geometry
1507 IF NEW.centroid IS NULL THEN
1508 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1511 -- merge in the name, re-init word vector
1512 IF NOT linkedPlacex.name IS NULL THEN
1513 NEW.name := linkedPlacex.name || NEW.name;
1514 name_vector := make_keywords(NEW.name);
1517 -- merge in extra tags
1518 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1520 -- mark the linked place (excludes from search results)
1521 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1523 -- keep a note of the node id in case we need it for wikipedia in a bit
1524 linked_node_id := linkedPlacex.osm_id;
1536 -- Name searches can be done for ways as well as relations
1537 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1539 -- not found one yet? how about doing a name search
1540 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1542 FOR linkedPlacex IN select placex.* from placex WHERE
1543 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1544 AND placex.rank_address = NEW.rank_address
1545 AND placex.place_id != NEW.place_id
1546 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1547 AND st_covers(NEW.geometry, placex.geometry)
1550 -- If we don't already have one use this as the centre point of the geometry
1551 IF NEW.centroid IS NULL THEN
1552 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1555 -- merge in the name, re-init word vector
1556 NEW.name := linkedPlacex.name || NEW.name;
1557 name_vector := make_keywords(NEW.name);
1559 -- merge in extra tags
1560 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1562 -- mark the linked place (excludes from search results)
1563 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1565 -- keep a note of the node id in case we need it for wikipedia in a bit
1566 linked_node_id := linkedPlacex.osm_id;
1570 IF NEW.centroid IS NOT NULL THEN
1571 place_centroid := NEW.centroid;
1572 -- Place might have had only a name tag before but has now received translations
1573 -- from the linked place. Make sure a name tag for the default language exists in
1575 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1576 default_language := get_country_language_code(NEW.calculated_country_code);
1577 IF default_language IS NOT NULL THEN
1578 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1579 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1580 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1581 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1587 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1588 IF NEW.importance is null THEN
1589 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.calculated_country_code) INTO NEW.wikipedia,NEW.importance;
1591 -- Still null? how about looking it up by the node id
1592 IF NEW.importance IS NULL THEN
1593 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;
1598 -- make sure all names are in the word table
1599 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1600 perform create_country(NEW.name, lower(NEW.country_code));
1603 NEW.parent_place_id = 0;
1604 parent_place_id_rank = 0;
1607 -- convert isin to array of tokenids
1608 isin_tokens := '{}'::int[];
1609 IF NEW.isin IS NOT NULL THEN
1610 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1611 IF array_upper(isin, 1) IS NOT NULL THEN
1612 FOR i IN 1..array_upper(isin, 1) LOOP
1613 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1614 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1615 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1616 isin_tokens := isin_tokens || address_street_word_id;
1619 -- merge word into address vector
1620 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1621 IF address_street_word_id IS NOT NULL THEN
1622 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1627 IF NEW.postcode IS NOT NULL THEN
1628 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1629 IF array_upper(isin, 1) IS NOT NULL THEN
1630 FOR i IN 1..array_upper(isin, 1) LOOP
1631 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1632 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1633 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1634 isin_tokens := isin_tokens || address_street_word_id;
1637 -- merge into address vector
1638 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1639 IF address_street_word_id IS NOT NULL THEN
1640 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1646 -- %NOTIGERDATA% IF 0 THEN
1647 -- for the USA we have an additional address table. Merge in zip codes from there too
1648 IF NEW.rank_search = 26 AND NEW.calculated_country_code = 'us' THEN
1649 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1650 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1651 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1652 isin_tokens := isin_tokens || address_street_word_id;
1654 -- also merge in the single word version
1655 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1656 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1659 -- %NOTIGERDATA% END IF;
1661 -- RAISE WARNING 'ISIN: %', isin_tokens;
1663 -- Process area matches
1664 location_rank_search := 0;
1665 location_distance := 0;
1666 location_parent := NULL;
1667 -- added ourself as address already
1668 address_havelevel[NEW.rank_address] := true;
1669 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1670 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1672 --RAISE WARNING ' AREA: %',location;
1674 IF location.rank_address != location_rank_search THEN
1675 location_rank_search := location.rank_address;
1676 IF location.isguess THEN
1677 location_distance := location.distance * 1.5;
1679 IF location.rank_address <= 12 THEN
1680 -- for county and above, if we have an area consider that exact
1681 -- (It would be nice to relax the constraint for places close to
1682 -- the boundary but we'd need the exact geometry for that. Too
1684 location_distance = 0;
1686 -- Below county level remain slightly fuzzy.
1687 location_distance := location.distance * 0.5;
1691 CONTINUE WHEN location.keywords <@ location_keywords;
1694 IF location.distance < location_distance OR NOT location.isguess THEN
1695 location_keywords := location.keywords;
1697 location_isaddress := NOT address_havelevel[location.rank_address];
1698 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1699 location_isaddress := ST_Contains(location_parent,location.centroid);
1702 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1703 -- Add it to the list of search terms
1704 IF location.rank_search > 4 THEN
1705 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1707 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1709 IF location_isaddress THEN
1711 address_havelevel[location.rank_address] := true;
1712 IF NOT location.isguess THEN
1713 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1716 IF location.rank_address > parent_place_id_rank THEN
1717 NEW.parent_place_id = location.place_id;
1718 parent_place_id_rank = location.rank_address;
1723 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1729 -- try using the isin value to find parent places
1730 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1731 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1732 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1733 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1735 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1737 --RAISE WARNING ' ISIN: %',location;
1739 IF location.rank_search > 4 THEN
1740 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1741 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1742 address_havelevel[location.rank_address] := true;
1744 IF location.rank_address > parent_place_id_rank THEN
1745 NEW.parent_place_id = location.place_id;
1746 parent_place_id_rank = location.rank_address;
1756 -- for long ways we should add search terms for the entire length
1757 IF st_length(NEW.geometry) > 0.05 THEN
1759 location_rank_search := 0;
1760 location_distance := 0;
1762 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1764 IF location.rank_address != location_rank_search THEN
1765 location_rank_search := location.rank_address;
1766 location_distance := location.distance * 1.5;
1769 IF location.rank_search > 4 AND location.distance < location_distance THEN
1771 -- Add it to the list of search terms
1772 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1773 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1781 -- if we have a name add this to the name search table
1782 IF NEW.name IS NOT NULL THEN
1784 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1785 result := add_location(NEW.place_id, NEW.calculated_country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1788 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1789 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.calculated_country_code, NEW.geometry);
1792 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);
1796 -- If we've not managed to pick up a better one - default centroid
1797 IF NEW.centroid IS NULL THEN
1798 NEW.centroid := place_centroid;
1806 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1812 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1814 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1815 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1816 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1817 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1819 IF OLD.rank_address < 30 THEN
1821 -- mark everything linked to this place for re-indexing
1822 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1823 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1824 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1826 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1827 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1829 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1830 b := deleteRoad(OLD.partition, OLD.place_id);
1832 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1833 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1834 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1835 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1836 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1840 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1842 IF OLD.rank_address < 26 THEN
1843 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1846 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1848 IF OLD.name is not null THEN
1849 b := deleteSearchName(OLD.partition, OLD.place_id);
1852 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1854 DELETE FROM place_addressline where place_id = OLD.place_id;
1856 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1858 -- remove from tables for special search
1859 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1860 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1862 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1865 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1873 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1879 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1881 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1882 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1883 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;
1885 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1891 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;
1893 -- interpolations are special
1894 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1895 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1904 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1909 existingplacex RECORD;
1910 existingline RECORD;
1911 existinggeometry GEOMETRY;
1912 existingplace_id BIGINT;
1917 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1918 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1919 -- filter wrong tupels
1920 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
1921 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1922 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1923 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1927 -- decide, whether it is an osm interpolation line => insert_osmline, or else just insert into placex
1928 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1929 -- Have we already done this place?
1930 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;
1932 -- Get the existing place_id
1933 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1935 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1936 IF existing.osm_type IS NULL THEN
1937 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1940 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1941 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1943 -- update method for interpolation lines: delete all old interpolation lines with same osm_id (update on place) and insert the new one(s) (they can be split up, if they have > 2 nodes)
1944 IF existingline.osm_id IS NOT NULL THEN
1945 delete from location_property_osmline where osm_id = NEW.osm_id;
1948 -- for interpolations invalidate all nodes on the line
1949 update placex p set indexed_status = 2
1950 from planet_osm_ways w
1951 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
1952 -- insert new line into location_property_osmline, use function insert_osmline
1955 IF existing.osm_type IS NULL THEN
1956 i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry);
1960 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1961 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1962 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
1963 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1964 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1965 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1966 OR existing.geometry::text != NEW.geometry::text
1971 housenumber = NEW.housenumber,
1972 street = NEW.street,
1973 addr_place = NEW.addr_place,
1975 postcode = NEW.postcode,
1976 country_code = NEW.country_code,
1977 extratags = NEW.extratags,
1978 admin_level = NEW.admin_level,
1979 geometry = NEW.geometry
1980 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1982 i = insert_osmline(NEW.osm_id, NEW.housenumber, NEW.street, NEW.addr_place, NEW.postcode, NEW.country_code, NEW.geometry);
1987 ELSE -- insert to placex
1989 -- Patch in additional country names
1990 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1991 SELECT name FROM country_name WHERE country_code = lower(NEW.country_code) INTO existing;
1992 IF existing.name IS NOT NULL THEN
1993 NEW.name = existing.name || NEW.name;
1997 -- Have we already done this place?
1998 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;
2000 -- Get the existing place_id
2001 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;
2003 -- Handle a place changing type by removing the old data
2004 -- My generated 'place' types are causing havok because they overlap with real keys
2005 -- TODO: move them to their own special purpose key/class to avoid collisions
2006 IF existing.osm_type IS NULL THEN
2007 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2010 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2011 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2014 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2015 AND st_area(existing.geometry) > 0.02
2016 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2017 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2019 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2020 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2024 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2025 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2027 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2028 IF existingplacex.osm_type IS NULL OR
2029 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2032 IF existingplacex.osm_type IS NOT NULL THEN
2033 -- sanity check: ignore admin_level changes on places with too many active children
2034 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2035 --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;
2036 --LIMIT INDEXING: IF i > 100000 THEN
2037 --LIMIT INDEXING: RETURN null;
2038 --LIMIT INDEXING: END IF;
2041 IF existing.osm_type IS NOT NULL THEN
2042 -- pathological case caused by the triggerless copy into place during initial import
2043 -- force delete even for large areas, it will be reinserted later
2044 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;
2045 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2048 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2049 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
2050 street, addr_place, isin, postcode, country_code, extratags, geometry)
2051 values (NEW.osm_type
2067 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2072 -- Various ways to do the update
2074 -- Debug, what's changed?
2076 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
2077 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
2079 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
2080 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
2082 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
2083 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
2085 IF coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '') THEN
2086 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.addr_place,NEW.addr_place;
2088 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
2089 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
2091 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
2092 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
2094 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
2095 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
2099 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2100 IF existing.geometry::text != NEW.geometry::text
2101 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2102 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2105 -- Get the version of the geometry actually used (in placex table)
2106 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;
2108 -- Performance limit
2109 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2111 -- 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
2112 update placex set indexed_status = 2 where indexed_status = 0 and
2113 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2114 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2115 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2117 update placex set indexed_status = 2 where indexed_status = 0 and
2118 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2119 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2120 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2127 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2128 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2129 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
2130 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
2131 OR coalesce(existing.addr_place, '') != coalesce(NEW.addr_place, '')
2132 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
2133 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
2134 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
2135 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2136 OR existing.geometry::text != NEW.geometry::text
2141 housenumber = NEW.housenumber,
2142 street = NEW.street,
2143 addr_place = NEW.addr_place,
2145 postcode = NEW.postcode,
2146 country_code = NEW.country_code,
2147 extratags = NEW.extratags,
2148 admin_level = NEW.admin_level,
2149 geometry = NEW.geometry
2150 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2153 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2154 IF NEW.postcode IS NULL THEN
2155 -- postcode was deleted, no longer retain in placex
2156 DELETE FROM placex where place_id = existingplacex.place_id;
2160 NEW.name := hstore('ref', NEW.postcode);
2165 housenumber = NEW.housenumber,
2166 street = NEW.street,
2167 addr_place = NEW.addr_place,
2169 postcode = NEW.postcode,
2170 country_code = NEW.country_code,
2171 parent_place_id = null,
2172 extratags = NEW.extratags,
2173 admin_level = CASE WHEN NEW.admin_level > 15 THEN 15 ELSE NEW.admin_level END,
2175 geometry = NEW.geometry
2176 where place_id = existingplacex.place_id;
2178 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2179 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2180 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2181 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2182 update location_property_osmline p set indexed_status = 2 from planet_osm_ways w where p.linegeo && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes);
2187 -- Abort the add (we modified the existing place instead)
2192 $$ LANGUAGE plpgsql;
2195 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2200 IF name is null THEN
2204 FOR j IN 1..array_upper(languagepref,1) LOOP
2205 IF name ? languagepref[j] THEN
2206 result := trim(name->languagepref[j]);
2207 IF result != '' THEN
2213 -- anything will do as a fallback - just take the first name type thing there is
2214 RETURN trim((avals(name))[1]);
2217 LANGUAGE plpgsql IMMUTABLE;
2220 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2231 search := ARRAY['ref'];
2234 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2237 select rank_address,name,distance,length(name::text) as namelength
2238 from place_addressline join placex on (address_place_id = placex.place_id)
2239 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2240 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2242 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2243 FOR j IN 1..array_upper(search, 1) LOOP
2244 FOR k IN 1..array_upper(location.name, 1) LOOP
2245 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
2246 result[(100 - location.rank_address)] := trim(location.name[k].value);
2247 found := location.rank_address;
2254 RETURN array_to_string(result,', ');
2259 --housenumber only needed for tiger data
2260 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2272 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2273 currresult := trim(get_name_by_language(location.name, languagepref));
2274 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2275 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2276 prevresult := currresult;
2280 RETURN array_to_string(result,', ');
2285 DROP TYPE IF EXISTS addressline CASCADE;
2286 create type addressline as (
2293 admin_level INTEGER,
2296 rank_address INTEGER,
2300 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2303 for_place_id BIGINT;
2308 countrylocation RECORD;
2309 searchcountrycode varchar(2);
2310 searchhousenumber TEXT;
2311 searchhousename HSTORE;
2312 searchrankaddress INTEGER;
2313 searchpostcode TEXT;
2319 -- first query osmline (interpolation lines)
2320 select parent_place_id, calculated_country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2321 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2322 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2323 IF for_place_id IS NOT NULL THEN
2324 searchhousenumber = in_housenumber::text;
2327 --then query tiger data
2328 -- %NOTIGERDATA% IF 0 THEN
2329 IF for_place_id IS NULL THEN
2330 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2331 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2332 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2333 IF for_place_id IS NOT NULL THEN
2334 searchhousenumber = in_housenumber::text;
2337 -- %NOTIGERDATA% END IF;
2339 -- %NOAUXDATA% IF 0 THEN
2340 IF for_place_id IS NULL THEN
2341 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2342 WHERE place_id = in_place_id
2343 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2345 -- %NOAUXDATA% END IF;
2347 IF for_place_id IS NULL THEN
2348 select parent_place_id, calculated_country_code, housenumber, rank_search, postcode, name, class, type from placex
2349 WHERE place_id = in_place_id and rank_search > 27
2350 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2353 IF for_place_id IS NULL THEN
2354 select coalesce(linked_place_id, place_id), calculated_country_code,
2355 housenumber, rank_search, postcode, null
2356 from placex where place_id = in_place_id
2357 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2360 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2363 hadcountry := false;
2365 select placex.place_id, osm_type, osm_id,
2366 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2367 class, type, admin_level, true as fromarea, true as isaddress,
2368 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2369 0 as distance, calculated_country_code, postcode
2371 where place_id = for_place_id
2373 --RAISE WARNING '%',location;
2374 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2375 searchcountrycode := location.calculated_country_code;
2377 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2378 location.isaddress := FALSE;
2380 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2381 searchpostcode := location.postcode;
2383 IF location.rank_address = 4 AND location.isaddress THEN
2386 IF location.rank_address < 4 AND NOT hadcountry THEN
2387 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2388 IF countryname IS NOT NULL THEN
2389 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2390 RETURN NEXT countrylocation;
2393 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2394 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2395 location.distance)::addressline;
2396 RETURN NEXT countrylocation;
2397 found := location.rank_address;
2401 select placex.place_id, osm_type, osm_id,
2402 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2403 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2404 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2405 admin_level, fromarea, isaddress,
2406 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,
2407 distance,calculated_country_code,postcode
2408 from place_addressline join placex on (address_place_id = placex.place_id)
2409 where place_addressline.place_id = for_place_id
2410 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2411 and address_place_id != for_place_id
2412 and (placex.calculated_country_code IS NULL OR searchcountrycode IS NULL OR placex.calculated_country_code = searchcountrycode)
2413 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2415 --RAISE WARNING '%',location;
2416 IF searchcountrycode IS NULL AND location.calculated_country_code IS NOT NULL THEN
2417 searchcountrycode := location.calculated_country_code;
2419 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2420 location.isaddress := FALSE;
2422 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2423 searchpostcode := location.postcode;
2425 IF location.rank_address = 4 AND location.isaddress THEN
2428 IF location.rank_address < 4 AND NOT hadcountry THEN
2429 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2430 IF countryname IS NOT NULL THEN
2431 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2432 RETURN NEXT countrylocation;
2435 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2436 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2437 location.distance)::addressline;
2438 RETURN NEXT countrylocation;
2439 found := location.rank_address;
2443 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2444 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2445 IF countryname IS NOT NULL THEN
2446 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2447 RETURN NEXT location;
2451 IF searchcountrycode IS NOT NULL THEN
2452 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2453 RETURN NEXT location;
2456 IF searchhousename IS NOT NULL THEN
2457 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2458 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2459 RETURN NEXT location;
2462 IF searchhousenumber IS NOT NULL THEN
2463 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2464 RETURN NEXT location;
2467 IF searchpostcode IS NOT NULL THEN
2468 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2469 RETURN NEXT location;
2478 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2481 numfeatures integer;
2485 housenumber = place.housenumber,
2486 street = place.street,
2487 addr_place = place.addr_place,
2489 postcode = place.postcode,
2490 country_code = place.country_code,
2491 parent_place_id = null
2493 where placex.place_id = search_place_id
2494 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2495 and place.class = placex.class and place.type = placex.type;
2496 update placex set indexed_status = 2 where place_id = search_place_id;
2497 update placex set indexed_status = 0 where place_id = search_place_id;
2503 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2509 ELSEIF rank < 4 THEN
2511 ELSEIF rank < 8 THEN
2513 ELSEIF rank < 12 THEN
2515 ELSEIF rank < 16 THEN
2517 ELSEIF rank = 16 THEN
2519 ELSEIF rank = 17 THEN
2520 RETURN 'Town / Island';
2521 ELSEIF rank = 18 THEN
2522 RETURN 'Village / Hamlet';
2523 ELSEIF rank = 20 THEN
2525 ELSEIF rank = 21 THEN
2526 RETURN 'Postcode Area';
2527 ELSEIF rank = 22 THEN
2528 RETURN 'Croft / Farm / Locality / Islet';
2529 ELSEIF rank = 23 THEN
2530 RETURN 'Postcode Area';
2531 ELSEIF rank = 25 THEN
2532 RETURN 'Postcode Point';
2533 ELSEIF rank = 26 THEN
2534 RETURN 'Street / Major Landmark';
2535 ELSEIF rank = 27 THEN
2536 RETURN 'Minory Street / Path';
2537 ELSEIF rank = 28 THEN
2538 RETURN 'House / Building';
2540 RETURN 'Other: '||rank;
2547 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2553 ELSEIF rank < 2 THEN
2555 ELSEIF rank < 4 THEN
2557 ELSEIF rank = 5 THEN
2559 ELSEIF rank < 8 THEN
2561 ELSEIF rank < 12 THEN
2563 ELSEIF rank < 16 THEN
2565 ELSEIF rank = 16 THEN
2567 ELSEIF rank = 17 THEN
2568 RETURN 'Town / Village / Hamlet';
2569 ELSEIF rank = 20 THEN
2571 ELSEIF rank = 21 THEN
2572 RETURN 'Postcode Area';
2573 ELSEIF rank = 22 THEN
2574 RETURN 'Croft / Farm / Locality / Islet';
2575 ELSEIF rank = 23 THEN
2576 RETURN 'Postcode Area';
2577 ELSEIF rank = 25 THEN
2578 RETURN 'Postcode Point';
2579 ELSEIF rank = 26 THEN
2580 RETURN 'Street / Major Landmark';
2581 ELSEIF rank = 27 THEN
2582 RETURN 'Minory Street / Path';
2583 ELSEIF rank = 28 THEN
2584 RETURN 'House / Building';
2586 RETURN 'Other: '||rank;
2593 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2594 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2599 place_centroid GEOMETRY;
2600 out_partition INTEGER;
2601 out_parent_place_id BIGINT;
2603 address_street_word_id INTEGER;
2608 place_centroid := ST_Centroid(pointgeo);
2609 out_partition := get_partition(in_countrycode);
2610 out_parent_place_id := null;
2612 address_street_word_id := get_name_id(make_standard_name(in_street));
2613 IF address_street_word_id IS NOT NULL THEN
2614 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2615 out_parent_place_id := location.place_id;
2619 IF out_parent_place_id IS NULL THEN
2620 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2621 out_parent_place_id := location.place_id;
2625 out_postcode := in_postcode;
2626 IF out_postcode IS NULL THEN
2627 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2629 IF out_postcode IS NULL THEN
2630 out_postcode := getNearestPostcode(out_partition, place_centroid);
2634 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2635 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2636 newpoints := newpoints + 1;
2643 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2650 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2651 IF members[i+1] = member THEN
2652 result := result || members[i];
2661 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2667 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2668 IF members[i+1] = ANY(memberLabels) THEN
2669 RETURN NEXT members[i];
2678 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2679 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2681 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2682 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
2683 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2684 ), '') AS bytea), 'UTF8');
2686 LANGUAGE SQL IMMUTABLE STRICT;
2688 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2692 RETURN decode_url_part(p);
2694 WHEN others THEN return null;
2697 LANGUAGE plpgsql IMMUTABLE;
2699 DROP TYPE wikipedia_article_match CASCADE;
2700 create type wikipedia_article_match as (
2706 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2712 wiki_article_title TEXT;
2713 wiki_article_language TEXT;
2714 result wikipedia_article_match;
2716 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'];
2718 WHILE langs[i] IS NOT NULL LOOP
2719 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2720 IF wiki_article is not null THEN
2721 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2722 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2723 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2724 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2725 wiki_article := replace(wiki_article,' ','_');
2726 IF strpos(wiki_article, ':') IN (3,4) THEN
2727 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2728 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2730 wiki_article_title := trim(wiki_article);
2731 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;
2734 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2735 from wikipedia_article
2736 where language = wiki_article_language and
2737 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2739 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2740 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2741 where wikipedia_redirect.language = wiki_article_language and
2742 (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'\\',''))
2743 order by importance desc limit 1 INTO result;
2745 IF result.language is not null THEN
2756 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2757 RETURNS SETOF GEOMETRY
2771 remainingdepth INTEGER;
2776 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2778 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2779 RETURN NEXT geometry;
2783 remainingdepth := maxdepth - 1;
2784 area := ST_AREA(geometry);
2785 IF remainingdepth < 1 OR area < maxarea THEN
2786 RETURN NEXT geometry;
2790 xmin := st_xmin(geometry);
2791 xmax := st_xmax(geometry);
2792 ymin := st_ymin(geometry);
2793 ymax := st_ymax(geometry);
2794 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2796 -- if the geometry completely covers the box don't bother to slice any more
2797 IF ST_AREA(secbox) = area THEN
2798 RETURN NEXT geometry;
2802 xmid := (xmin+xmax)/2;
2803 ymid := (ymin+ymax)/2;
2806 FOR seg IN 1..4 LOOP
2809 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2812 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2815 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2818 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2821 IF st_intersects(geometry, secbox) THEN
2822 secgeo := st_intersection(geometry, secbox);
2823 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2824 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2825 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2827 RETURN NEXT geo.geom;
2839 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2840 RETURNS SETOF GEOMETRY
2845 -- 10000000000 is ~~ 1x1 degree
2846 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2847 RETURN NEXT geo.geom;
2855 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2859 osmtype character(1);
2863 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2864 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2865 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2866 -- force delete from place/placex by making it a very small geometry
2867 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;
2868 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2875 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2883 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2884 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2885 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2886 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2887 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2888 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2889 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));
2890 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2891 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));
2897 ELSEIF rank < 18 THEN
2899 ELSEIF rank < 20 THEN
2901 ELSEIF rank = 21 THEN
2903 ELSEIF rank < 24 THEN
2905 ELSEIF rank < 26 THEN
2906 diameter := 0.002; -- 100 to 200 meters
2907 ELSEIF rank < 28 THEN
2908 diameter := 0.001; -- 50 to 100 meters
2910 IF diameter > 0 THEN
2912 -- roads may cause reparenting for >27 rank places
2913 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2914 ELSEIF rank >= 16 THEN
2915 -- up to rank 16, street-less addresses may need reparenting
2916 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);
2918 -- for all other places the search terms may change as well
2919 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);