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_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
260 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
261 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
268 postcode := upper(postcode);
270 IF country_code = 'gb' THEN
271 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
274 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
277 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
282 ELSEIF country_code = 'sg' THEN
283 IF postcode ~ '^([0-9]{6})$' THEN
288 ELSEIF country_code = 'de' THEN
289 IF postcode ~ '^([0-9]{5})$' THEN
295 -- Guess at the postcode format and coverage (!)
296 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
300 -- Does it look splitable into and area and local code?
301 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
303 IF part IS NOT NULL THEN
306 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
315 LANGUAGE plpgsql IMMUTABLE;
317 -- Find the nearest artificial postcode for the given geometry.
318 -- TODO For areas there should not be more than two inside the geometry.
319 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
324 -- If the geometry is an area then only one postcode must be within
325 -- that area, otherwise consider the area as not having a postcode.
326 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
328 SELECT min(postcode) as postcode, count(*) as cnt FROM
329 (SELECT postcode FROM location_postcode
330 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
334 ELSEIF item.cnt = 1 THEN
335 RETURN item.postcode;
341 SELECT postcode FROM location_postcode
342 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
343 AND location_postcode.country_code = country
344 ORDER BY ST_Distance(geom, location_postcode.geometry)
347 RETURN item.postcode;
356 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
365 FOR item IN SELECT (each(src)).* LOOP
367 s := make_standard_name(item.value);
368 w := getorcreate_country(s, lookup_country_code);
370 words := regexp_split_to_array(item.value, E'[,;()]');
371 IF array_upper(words, 1) != 1 THEN
372 FOR j IN 1..array_upper(words, 1) LOOP
373 s := make_standard_name(words[j]);
375 w := getorcreate_country(s, lookup_country_code);
384 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
394 result := '{}'::INTEGER[];
396 FOR item IN SELECT (each(src)).* LOOP
398 s := make_standard_name(item.value);
400 w := getorcreate_name_id(s, item.value);
402 IF not(ARRAY[w] <@ result) THEN
403 result := result || w;
406 w := getorcreate_word_id(s);
408 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
409 result := result || w;
412 words := string_to_array(s, ' ');
413 IF array_upper(words, 1) IS NOT NULL THEN
414 FOR j IN 1..array_upper(words, 1) LOOP
415 IF (words[j] != '') THEN
416 w = getorcreate_word_id(words[j]);
417 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
418 result := result || w;
424 words := regexp_split_to_array(item.value, E'[,;()]');
425 IF array_upper(words, 1) != 1 THEN
426 FOR j IN 1..array_upper(words, 1) LOOP
427 s := make_standard_name(words[j]);
429 w := getorcreate_word_id(s);
430 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
431 result := result || w;
437 s := regexp_replace(item.value, '市$', '');
438 IF s != item.value THEN
439 s := make_standard_name(s);
441 w := getorcreate_name_id(s, item.value);
442 IF NOT (ARRAY[w] <@ result) THEN
443 result := result || w;
453 LANGUAGE plpgsql IMMUTABLE;
455 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
465 result := '{}'::INTEGER[];
467 s := make_standard_name(src);
468 w := getorcreate_name_id(s, src);
470 IF NOT (ARRAY[w] <@ result) THEN
471 result := result || w;
474 w := getorcreate_word_id(s);
476 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
477 result := result || w;
480 words := string_to_array(s, ' ');
481 IF array_upper(words, 1) IS NOT NULL THEN
482 FOR j IN 1..array_upper(words, 1) LOOP
483 IF (words[j] != '') THEN
484 w = getorcreate_word_id(words[j]);
485 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
486 result := result || w;
492 words := regexp_split_to_array(src, E'[,;()]');
493 IF array_upper(words, 1) != 1 THEN
494 FOR j IN 1..array_upper(words, 1) LOOP
495 s := make_standard_name(words[j]);
497 w := getorcreate_word_id(s);
498 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
499 result := result || w;
505 s := regexp_replace(src, '市$', '');
507 s := make_standard_name(s);
509 w := getorcreate_name_id(s, src);
510 IF NOT (ARRAY[w] <@ result) THEN
511 result := result || w;
519 LANGUAGE plpgsql IMMUTABLE;
521 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
524 place_centre GEOMETRY;
527 place_centre := ST_PointOnSurface(place);
529 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
531 -- Try for a OSM polygon
532 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
534 RETURN nearcountry.country_code;
537 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
539 -- Try for OSM fallback data
540 -- The order is to deal with places like HongKong that are 'states' within another polygon
541 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
543 RETURN nearcountry.country_code;
546 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
548 -- Natural earth data
549 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
551 RETURN nearcountry.country_code;
554 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
557 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
559 RETURN nearcountry.country_code;
562 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
564 -- Natural earth data
565 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
567 RETURN nearcountry.country_code;
573 LANGUAGE plpgsql IMMUTABLE;
575 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
580 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
582 RETURN lower(nearcountry.country_default_language_code);
587 LANGUAGE plpgsql IMMUTABLE;
589 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
594 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
596 RETURN lower(nearcountry.country_default_language_codes);
601 LANGUAGE plpgsql IMMUTABLE;
603 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
608 FOR nearcountry IN select partition from country_name where country_code = in_country_code
610 RETURN nearcountry.partition;
615 LANGUAGE plpgsql IMMUTABLE;
617 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
621 DELETE FROM location_area where place_id = OLD_place_id;
622 -- TODO:location_area
628 CREATE OR REPLACE FUNCTION add_location(
630 country_code varchar(2),
634 rank_address INTEGER,
650 IF rank_search > 25 THEN
651 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
654 x := deleteLocationArea(partition, place_id, rank_search);
656 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
658 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
659 postcode := upper(trim (in_postcode));
662 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
663 centroid := ST_Centroid(geometry);
665 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
666 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
672 IF rank_address = 0 THEN
674 ELSEIF rank_search <= 14 THEN
676 ELSEIF rank_search <= 15 THEN
678 ELSEIF rank_search <= 16 THEN
680 ELSEIF rank_search <= 17 THEN
682 ELSEIF rank_search <= 21 THEN
684 ELSEIF rank_search = 25 THEN
688 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
690 secgeo := ST_Buffer(geometry, diameter);
691 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
701 -- find the parent road of the cut road parts
702 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
703 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
708 parent_place_id BIGINT;
709 address_street_word_ids INTEGER[];
715 addr_street = street;
718 IF addr_street is null and addr_place is null THEN
719 select nodes from planet_osm_ways where id = wayid INTO waynodes;
720 FOR location IN SELECT placex.address from placex
721 where osm_type = 'N' and osm_id = ANY(waynodes)
722 and placex.address is not null
723 and (placex.address ? 'street' or placex.address ? 'place')
724 and indexed_status < 100
726 addr_street = location.address->'street';
727 addr_place = location.address->'place';
731 IF addr_street IS NOT NULL THEN
732 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
733 IF address_street_word_ids IS NOT NULL THEN
734 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
735 parent_place_id := location.place_id;
740 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
741 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
742 IF address_street_word_ids IS NOT NULL THEN
743 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
744 parent_place_id := location.place_id;
749 IF parent_place_id is null THEN
750 FOR location IN SELECT place_id FROM placex
751 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
752 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
753 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
754 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
756 parent_place_id := location.place_id;
760 IF parent_place_id is null THEN
764 RETURN parent_place_id;
770 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
773 NEW.place_id := nextval('seq_place');
774 NEW.indexed_date := now();
776 IF NEW.indexed_status IS NULL THEN
777 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
778 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
779 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
783 NEW.indexed_status := 1; --STATUS_NEW
784 NEW.country_code := lower(get_country_code(NEW.linegeo));
786 NEW.partition := get_partition(NEW.country_code);
787 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
796 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
802 country_code VARCHAR(2);
803 default_language VARCHAR(10);
808 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
810 NEW.place_id := nextval('seq_place');
811 NEW.indexed_status := 1; --STATUS_NEW
813 NEW.country_code := lower(get_country_code(NEW.geometry));
815 NEW.partition := get_partition(NEW.country_code);
816 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
818 -- copy 'name' to or from the default language (if there is a default language)
819 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
820 default_language := get_country_language_code(NEW.country_code);
821 IF default_language IS NOT NULL THEN
822 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
823 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
824 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
825 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
830 IF NEW.osm_type = 'X' THEN
831 -- E'X'ternal records should already be in the right format so do nothing
833 NEW.rank_search := 30;
834 NEW.rank_address := NEW.rank_search;
836 -- By doing in postgres we have the country available to us - currently only used for postcode
837 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
839 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
840 -- most likely just a part of a multipolygon postcode boundary, throw it away
844 NEW.name := hstore('ref', NEW.address->'postcode');
846 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
847 INTO NEW.rank_search, NEW.rank_address;
849 ELSEIF NEW.class = 'place' THEN
850 IF NEW.type in ('continent') THEN
851 NEW.rank_search := 2;
852 NEW.rank_address := NEW.rank_search;
853 NEW.country_code := NULL;
854 ELSEIF NEW.type in ('sea') THEN
855 NEW.rank_search := 2;
856 NEW.rank_address := 0;
857 NEW.country_code := NULL;
858 ELSEIF NEW.type in ('country') THEN
859 NEW.rank_search := 4;
860 NEW.rank_address := NEW.rank_search;
861 ELSEIF NEW.type in ('state') THEN
862 NEW.rank_search := 8;
863 NEW.rank_address := NEW.rank_search;
864 ELSEIF NEW.type in ('region') THEN
865 NEW.rank_search := 18; -- dropped from previous value of 10
866 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
867 ELSEIF NEW.type in ('county') THEN
868 NEW.rank_search := 12;
869 NEW.rank_address := NEW.rank_search;
870 ELSEIF NEW.type in ('city') THEN
871 NEW.rank_search := 16;
872 NEW.rank_address := NEW.rank_search;
873 ELSEIF NEW.type in ('island') THEN
874 NEW.rank_search := 17;
875 NEW.rank_address := 0;
876 ELSEIF NEW.type in ('town') THEN
877 NEW.rank_search := 18;
878 NEW.rank_address := 16;
879 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
880 NEW.rank_search := 19;
881 NEW.rank_address := 16;
882 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
883 NEW.rank_search := 20;
884 NEW.rank_address := NEW.rank_search;
885 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
886 NEW.rank_search := 20;
887 NEW.rank_address := 0;
888 -- Irish townlands, tagged as place=locality and locality=townland
889 IF (NEW.extratags -> 'locality') = 'townland' THEN
890 NEW.rank_address := 20;
892 ELSEIF NEW.type in ('neighbourhood') THEN
893 NEW.rank_search := 22;
894 NEW.rank_address := 22;
895 ELSEIF NEW.type in ('house','building') THEN
896 NEW.rank_search := 30;
897 NEW.rank_address := NEW.rank_search;
898 ELSEIF NEW.type in ('houses') THEN
899 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
900 NEW.rank_search := 28;
901 NEW.rank_address := 0;
904 ELSEIF NEW.class = 'boundary' THEN
905 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
906 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
909 NEW.rank_search := NEW.admin_level * 2;
910 IF NEW.type = 'administrative' THEN
911 NEW.rank_address := NEW.rank_search;
913 NEW.rank_address := 0;
915 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
916 NEW.rank_search := 22;
917 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
918 NEW.rank_address := NEW.rank_search;
920 NEW.rank_address := 0;
922 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
923 NEW.rank_search := 18;
924 NEW.rank_address := 0;
925 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
926 NEW.rank_search := 4;
927 NEW.rank_address := NEW.rank_search;
928 -- any feature more than 5 square miles is probably worth indexing
929 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
930 NEW.rank_search := 22;
931 NEW.rank_address := 0;
932 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
934 ELSEIF NEW.class = 'waterway' THEN
935 IF NEW.osm_type = 'R' THEN
936 NEW.rank_search := 16;
938 NEW.rank_search := 17;
940 NEW.rank_address := 0;
941 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
942 NEW.rank_search := 27;
943 NEW.rank_address := NEW.rank_search;
944 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
945 NEW.rank_search := 26;
946 NEW.rank_address := NEW.rank_search;
947 ELSEIF NEW.class = 'mountain_pass' THEN
948 NEW.rank_search := 20;
949 NEW.rank_address := 0;
954 IF NEW.rank_search > 30 THEN
955 NEW.rank_search := 30;
958 IF NEW.rank_address > 30 THEN
959 NEW.rank_address := 30;
962 IF (NEW.extratags -> 'capital') = 'yes' THEN
963 NEW.rank_search := NEW.rank_search - 1;
966 -- a country code make no sense below rank 4 (country)
967 IF NEW.rank_search < 4 THEN
968 NEW.country_code := NULL;
971 -- Block import below rank 22
972 -- IF NEW.rank_search > 22 THEN
976 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
978 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
980 IF NEW.rank_address > 0 THEN
981 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
982 -- Performance: We just can't handle re-indexing for country level changes
983 IF st_area(NEW.geometry) < 1 THEN
984 -- mark items within the geometry for re-indexing
985 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
987 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
988 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
989 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 address ? 'place'));
990 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
991 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 address ? 'place'));
994 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
996 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
997 IF NEW.type='postcode' THEN
999 ELSEIF NEW.rank_search < 16 THEN
1001 ELSEIF NEW.rank_search < 18 THEN
1003 ELSEIF NEW.rank_search < 20 THEN
1005 ELSEIF NEW.rank_search = 21 THEN
1007 ELSEIF NEW.rank_search < 24 THEN
1009 ELSEIF NEW.rank_search < 26 THEN
1010 diameter := 0.002; -- 100 to 200 meters
1011 ELSEIF NEW.rank_search < 28 THEN
1012 diameter := 0.001; -- 50 to 100 meters
1014 IF diameter > 0 THEN
1015 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1016 IF NEW.rank_search >= 26 THEN
1017 -- roads may cause reparenting for >27 rank places
1018 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1019 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1020 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1021 ELSEIF NEW.rank_search >= 16 THEN
1022 -- up to rank 16, street-less addresses may need reparenting
1023 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 address ? 'place');
1025 -- for all other places the search terms may change as well
1026 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);
1033 -- add to tables for special search
1034 -- Note: won't work on initial import because the classtype tables
1035 -- do not yet exist. It won't hurt either.
1036 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1037 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1039 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1040 USING NEW.place_id, ST_Centroid(NEW.geometry);
1049 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1053 place_centroid GEOMETRY;
1057 startnumber INTEGER;
1062 sectiongeo GEOMETRY;
1063 interpol_postcode TEXT;
1067 IF OLD.indexed_status = 100 THEN
1068 delete from location_property_osmline where place_id = OLD.place_id;
1072 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1076 NEW.interpolationtype = NEW.address->'interpolation';
1078 place_centroid := ST_PointOnSurface(NEW.linegeo);
1079 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1080 NEW.address->'place',
1081 NEW.partition, place_centroid, NEW.linegeo);
1083 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1084 interpol_postcode := NEW.address->'postcode';
1085 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1087 interpol_postcode := NULL;
1090 -- if the line was newly inserted, split the line as necessary
1091 IF OLD.indexed_status = 1 THEN
1092 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1094 IF array_upper(waynodes, 1) IS NULL THEN
1098 linegeo := NEW.linegeo;
1099 startnumber := NULL;
1101 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1103 select osm_id, address, geometry
1104 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1105 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1106 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1107 IF nextnode.osm_id IS NOT NULL THEN
1108 --RAISE NOTICE 'place_id is not null';
1109 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1110 -- Make sure that the point is actually on the line. That might
1111 -- be a bit paranoid but ensures that the algorithm still works
1112 -- should osm2pgsql attempt to repair geometries.
1113 splitline := split_line_on_node(linegeo, nextnode.geometry);
1114 sectiongeo := ST_GeometryN(splitline, 1);
1115 linegeo := ST_GeometryN(splitline, 2);
1117 sectiongeo = linegeo;
1119 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1121 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1122 AND startnumber != endnumber
1123 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1125 IF (startnumber > endnumber) THEN
1126 housenum := endnumber;
1127 endnumber := startnumber;
1128 startnumber := housenum;
1129 sectiongeo := ST_Reverse(sectiongeo);
1132 -- determine postcode
1133 postcode := coalesce(interpol_postcode,
1134 prevnode.address->'postcode',
1135 nextnode.address->'postcode',
1138 IF postcode is NULL THEN
1139 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1141 IF postcode is NULL THEN
1142 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1145 IF NEW.startnumber IS NULL THEN
1146 NEW.startnumber := startnumber;
1147 NEW.endnumber := endnumber;
1148 NEW.linegeo := sectiongeo;
1149 NEW.postcode := postcode;
1151 insert into location_property_osmline
1152 (linegeo, partition, osm_id, parent_place_id,
1153 startnumber, endnumber, interpolationtype,
1154 address, postcode, country_code,
1155 geometry_sector, indexed_status)
1156 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1157 startnumber, endnumber, NEW.interpolationtype,
1158 NEW.address, postcode,
1159 NEW.country_code, NEW.geometry_sector, 0);
1163 -- early break if we are out of line string,
1164 -- might happen when a line string loops back on itself
1165 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1169 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1170 prevnode := nextnode;
1175 -- marking descendants for reparenting is not needed, because there are
1176 -- actually no descendants for interpolation lines
1182 -- Trigger for updates of location_postcode
1184 -- Computes the parent object the postcode most likely refers to.
1185 -- This will be the place that determines the address displayed when
1186 -- searching for this postcode.
1187 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1194 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1198 NEW.indexed_date = now();
1200 partition := get_partition(NEW.country_code);
1202 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1203 INTO NEW.rank_search, NEW.rank_address;
1205 NEW.parent_place_id = 0;
1208 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1209 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1211 NEW.parent_place_id = location.place_id;
1219 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1224 place_centroid GEOMETRY;
1226 search_maxdistance FLOAT[];
1227 search_mindistance FLOAT[];
1228 address_havelevel BOOLEAN[];
1235 relation_members TEXT[];
1237 linkedplacex RECORD;
1238 search_diameter FLOAT;
1239 search_prevdiameter FLOAT;
1240 search_maxrank INTEGER;
1241 address_maxrank INTEGER;
1242 address_street_word_id INTEGER;
1243 address_street_word_ids INTEGER[];
1244 parent_place_id_rank BIGINT;
1252 location_rank_search INTEGER;
1253 location_distance FLOAT;
1254 location_parent GEOMETRY;
1255 location_isaddress BOOLEAN;
1256 location_keywords INTEGER[];
1258 default_language TEXT;
1259 name_vector INTEGER[];
1260 nameaddress_vector INTEGER[];
1262 linked_node_id BIGINT;
1263 linked_importance FLOAT;
1264 linked_wikipedia TEXT;
1269 IF OLD.indexed_status = 100 THEN
1270 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1271 delete from placex where place_id = OLD.place_id;
1275 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1279 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1281 NEW.indexed_date = now();
1283 result := deleteSearchName(NEW.partition, NEW.place_id);
1284 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1285 result := deleteRoad(NEW.partition, NEW.place_id);
1286 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1287 UPDATE placex set linked_place_id = null, indexed_status = 2
1288 where linked_place_id = NEW.place_id;
1289 -- update not necessary for osmline, cause linked_place_id does not exist
1291 IF NEW.linked_place_id is not null THEN
1292 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1296 --DEBUG: RAISE WARNING 'Copy over address tags';
1297 IF NEW.address is not NULL THEN
1298 IF NEW.address ? 'conscriptionnumber' THEN
1299 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1300 IF NEW.address ? 'streetnumber' THEN
1301 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1302 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1304 NEW.housenumber := NEW.address->'conscriptionnumber';
1306 ELSEIF NEW.address ? 'streetnumber' THEN
1307 NEW.housenumber := NEW.address->'streetnumber';
1308 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1309 ELSEIF NEW.address ? 'housenumber' THEN
1310 NEW.housenumber := NEW.address->'housenumber';
1311 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1314 addr_street = NEW.address->'street';
1315 addr_place = NEW.address->'place';
1317 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1318 i := getorcreate_postcode_id(NEW.address->'postcode');
1322 -- Speed up searches - just use the centroid of the feature
1323 -- cheaper but less acurate
1324 place_centroid := ST_PointOnSurface(NEW.geometry);
1325 NEW.centroid := null;
1326 NEW.postcode := null;
1327 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1329 -- recalculate country and partition
1330 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1331 -- for countries, believe the mapped country code,
1332 -- so that we remain in the right partition if the boundaries
1334 NEW.country_code := lower(NEW.address->'country');
1335 NEW.partition := get_partition(lower(NEW.country_code));
1336 IF NEW.partition = 0 THEN
1337 NEW.country_code := lower(get_country_code(place_centroid));
1338 NEW.partition := get_partition(NEW.country_code);
1341 IF NEW.rank_search >= 4 THEN
1342 NEW.country_code := lower(get_country_code(place_centroid));
1344 NEW.country_code := NULL;
1346 NEW.partition := get_partition(NEW.country_code);
1348 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1350 -- waterway ways are linked when they are part of a relation and have the same class/type
1351 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1352 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1354 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1355 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1356 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1357 FOR linked_node_id IN SELECT place_id FROM placex
1358 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1359 and class = NEW.class and type = NEW.type
1360 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1362 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1367 --DEBUG: RAISE WARNING 'Waterway processed';
1370 -- Adding ourselves to the list simplifies address calculations later
1371 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1372 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1374 -- What level are we searching from
1375 search_maxrank := NEW.rank_search;
1377 -- Thought this wasn't needed but when we add new languages to the country_name table
1378 -- we need to update the existing names
1379 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1380 default_language := get_country_language_code(NEW.country_code);
1381 IF default_language IS NOT NULL THEN
1382 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1383 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1384 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1385 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1389 --DEBUG: RAISE WARNING 'Local names updated';
1391 -- Initialise the name vector using our name
1392 name_vector := make_keywords(NEW.name);
1393 nameaddress_vector := '{}'::int[];
1396 address_havelevel[i] := false;
1399 NEW.importance := null;
1400 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1401 IF NEW.importance IS NULL THEN
1402 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;
1405 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1407 -- ---------------------------------------------------------------------------
1408 -- For low level elements we inherit from our parent road
1409 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1411 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1413 -- We won't get a better centroid, besides these places are too small to care
1414 NEW.centroid := place_centroid;
1416 NEW.parent_place_id := null;
1418 -- if we have a POI and there is no address information,
1419 -- see if we can get it from a surrounding building
1420 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1421 AND NEW.housenumber IS NULL THEN
1422 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1423 and address is not null
1424 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1425 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1428 NEW.housenumber := location.address->'housenumber';
1429 addr_street := location.address->'street';
1430 addr_place := location.address->'place';
1431 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1435 -- We have to find our parent road.
1436 -- Copy data from linked items (points on ways, addr:street links, relations)
1438 -- Is this object part of a relation?
1439 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1441 -- At the moment we only process one type of relation - associatedStreet
1442 IF relation.tags @> ARRAY['associatedStreet'] THEN
1443 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1444 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1445 --RAISE WARNING 'node in relation %',relation;
1446 SELECT place_id from placex where osm_type = 'W'
1447 and osm_id = substring(relation.members[i],2,200)::bigint
1448 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1453 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1455 -- Note that addr:street links can only be indexed once the street itself is indexed
1456 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1457 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1458 IF address_street_word_ids IS NOT NULL THEN
1459 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1460 NEW.parent_place_id := location.place_id;
1464 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1466 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1467 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1468 IF address_street_word_ids IS NOT NULL THEN
1469 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1470 NEW.parent_place_id := location.place_id;
1474 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1476 -- Is this node part of an interpolation?
1477 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1479 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1480 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1483 NEW.parent_place_id := location.parent_place_id;
1486 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1488 -- Is this node part of a way?
1489 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1491 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.address from placex p, planet_osm_ways w
1492 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)
1494 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1496 -- Way IS a road then we are on it - that must be our road
1497 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1498 --RAISE WARNING 'node in way that is a street %',location;
1499 NEW.parent_place_id := location.place_id;
1501 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1503 -- If the way mentions a street or place address, try that for parenting.
1504 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1505 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1506 IF address_street_word_ids IS NOT NULL THEN
1507 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1508 NEW.parent_place_id := linkedplacex.place_id;
1512 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1514 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1515 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1516 IF address_street_word_ids IS NOT NULL THEN
1517 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1518 NEW.parent_place_id := linkedplacex.place_id;
1522 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1524 -- Is the WAY part of a relation
1525 IF NEW.parent_place_id IS NULL THEN
1526 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1528 -- At the moment we only process one type of relation - associatedStreet
1529 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1530 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1531 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1532 --RAISE WARNING 'node in way that is in a relation %',relation;
1533 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1534 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1540 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1546 -- Still nothing, just use the nearest road
1547 IF NEW.parent_place_id IS NULL THEN
1548 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1549 NEW.parent_place_id := location.place_id;
1552 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1555 -- If we didn't find any road fallback to standard method
1556 IF NEW.parent_place_id IS NOT NULL THEN
1558 -- Get the details of the parent road
1559 select * from search_name where place_id = NEW.parent_place_id INTO location;
1560 NEW.country_code := location.country_code;
1561 --DEBUG: RAISE WARNING 'Got parent details from search name';
1563 -- determine postcode
1564 IF NEW.rank_search > 4 THEN
1565 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1566 NEW.postcode = NEW.address->'postcode';
1568 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1570 IF NEW.postcode is null THEN
1571 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1575 -- If there is no name it isn't searchable, don't bother to create a search record
1576 IF NEW.name is NULL THEN
1577 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1581 -- Merge address from parent
1582 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1583 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1585 -- Performance, it would be more acurate to do all the rest of the import
1586 -- process but it takes too long
1587 -- Just be happy with inheriting from parent road only
1589 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1590 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1591 --DEBUG: RAISE WARNING 'Place added to location table';
1594 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1595 --DEBUG: RAISE WARNING 'Place added to search table';
1602 -- ---------------------------------------------------------------------------
1604 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1606 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1608 -- see if we have any special relation members
1609 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1610 --DEBUG: RAISE WARNING 'Got relation members';
1612 IF relation_members IS NOT NULL THEN
1613 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1614 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1616 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1617 and osm_id = substring(relMember.member,2,10000)::bigint
1618 and class = 'place' order by rank_search desc limit 1 LOOP
1620 -- If we don't already have one use this as the centre point of the geometry
1621 IF NEW.centroid IS NULL THEN
1622 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1625 -- merge in the label name, re-init word vector
1626 IF NOT linkedPlacex.name IS NULL THEN
1627 NEW.name := linkedPlacex.name || NEW.name;
1628 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1631 -- merge in extra tags
1632 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1634 -- mark the linked place (excludes from search results)
1635 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1637 -- keep a note of the node id in case we need it for wikipedia in a bit
1638 linked_node_id := linkedPlacex.osm_id;
1639 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1640 --DEBUG: RAISE WARNING 'Linked label member';
1645 IF NEW.centroid IS NULL THEN
1647 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1648 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1650 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1651 and osm_id = substring(relMember.member,2,10000)::bigint
1652 and class = 'place' order by rank_search desc limit 1 LOOP
1654 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1655 -- But that can be fixed by explicitly setting the label in the data
1656 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1657 AND NEW.rank_address = linkedPlacex.rank_address THEN
1659 -- If we don't already have one use this as the centre point of the geometry
1660 IF NEW.centroid IS NULL THEN
1661 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1664 -- merge in the name, re-init word vector
1665 IF NOT linkedPlacex.name IS NULL THEN
1666 NEW.name := linkedPlacex.name || NEW.name;
1667 name_vector := make_keywords(NEW.name);
1670 -- merge in extra tags
1671 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1673 -- mark the linked place (excludes from search results)
1674 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1676 -- keep a note of the node id in case we need it for wikipedia in a bit
1677 linked_node_id := linkedPlacex.osm_id;
1678 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1679 --DEBUG: RAISE WARNING 'Linked admin_center';
1691 -- Name searches can be done for ways as well as relations
1692 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1694 -- not found one yet? how about doing a name search
1695 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1697 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1698 FOR linkedPlacex IN select placex.* from placex WHERE
1699 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1700 AND placex.rank_address = NEW.rank_address
1701 AND placex.place_id != NEW.place_id
1702 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1703 AND st_covers(NEW.geometry, placex.geometry)
1705 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1706 -- If we don't already have one use this as the centre point of the geometry
1707 IF NEW.centroid IS NULL THEN
1708 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1711 -- merge in the name, re-init word vector
1712 NEW.name := linkedPlacex.name || NEW.name;
1713 name_vector := make_keywords(NEW.name);
1715 -- merge in extra tags
1716 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1718 -- mark the linked place (excludes from search results)
1719 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1721 -- keep a note of the node id in case we need it for wikipedia in a bit
1722 linked_node_id := linkedPlacex.osm_id;
1723 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1724 --DEBUG: RAISE WARNING 'Linked named place';
1728 IF NEW.centroid IS NOT NULL THEN
1729 place_centroid := NEW.centroid;
1730 -- Place might have had only a name tag before but has now received translations
1731 -- from the linked place. Make sure a name tag for the default language exists in
1733 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1734 default_language := get_country_language_code(NEW.country_code);
1735 IF default_language IS NOT NULL THEN
1736 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1737 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1738 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1739 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1743 --DEBUG: RAISE WARNING 'Names updated from linked places';
1746 -- Use the maximum importance if a one could be computed from the linked object.
1747 IF linked_importance is not null AND
1748 (NEW.importance is null or NEW.importance < linked_importance) THEN
1749 NEW.importance = linked_importance;
1752 -- Still null? how about looking it up by the node id
1753 IF NEW.importance IS NULL THEN
1754 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1755 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;
1760 -- make sure all names are in the word table
1761 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1762 perform create_country(NEW.name, lower(NEW.country_code));
1763 --DEBUG: RAISE WARNING 'Country names updated';
1766 NEW.parent_place_id = 0;
1767 parent_place_id_rank = 0;
1770 -- convert isin to array of tokenids
1771 --DEBUG: RAISE WARNING 'Starting address search';
1772 isin_tokens := '{}'::int[];
1773 IF NEW.address IS NOT NULL THEN
1774 isin := avals(NEW.address);
1775 IF array_upper(isin, 1) IS NOT NULL THEN
1776 FOR i IN 1..array_upper(isin, 1) LOOP
1777 -- TODO further split terms with comma and semicolon
1778 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1779 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1780 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1781 isin_tokens := isin_tokens || address_street_word_id;
1784 -- merge word into address vector
1785 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1786 IF address_street_word_id IS NOT NULL THEN
1787 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1793 -- %NOTIGERDATA% IF 0 THEN
1794 -- for the USA we have an additional address table. Merge in zip codes from there too
1795 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1796 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1797 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1798 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1799 isin_tokens := isin_tokens || address_street_word_id;
1801 -- also merge in the single word version
1802 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1803 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1806 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1807 -- %NOTIGERDATA% END IF;
1809 -- RAISE WARNING 'ISIN: %', isin_tokens;
1811 -- Process area matches
1812 location_rank_search := 0;
1813 location_distance := 0;
1814 location_parent := NULL;
1815 -- added ourself as address already
1816 address_havelevel[NEW.rank_address] := true;
1817 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1819 SELECT * from getNearFeatures(NEW.partition,
1820 CASE WHEN NEW.rank_search >= 26
1821 AND NEW.rank_search < 30
1823 ELSE place_centroid END,
1824 search_maxrank, isin_tokens)
1826 IF location.rank_address != location_rank_search THEN
1827 location_rank_search := location.rank_address;
1828 IF location.isguess THEN
1829 location_distance := location.distance * 1.5;
1831 IF location.rank_address <= 12 THEN
1832 -- for county and above, if we have an area consider that exact
1833 -- (It would be nice to relax the constraint for places close to
1834 -- the boundary but we'd need the exact geometry for that. Too
1836 location_distance = 0;
1838 -- Below county level remain slightly fuzzy.
1839 location_distance := location.distance * 0.5;
1843 CONTINUE WHEN location.keywords <@ location_keywords;
1846 IF location.distance < location_distance OR NOT location.isguess THEN
1847 location_keywords := location.keywords;
1849 location_isaddress := NOT address_havelevel[location.rank_address];
1850 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1851 location_isaddress := ST_Contains(location_parent,location.centroid);
1854 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1855 -- Add it to the list of search terms
1856 IF location.rank_search > 4 THEN
1857 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1859 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1860 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1862 IF location_isaddress THEN
1863 -- add postcode if we have one
1864 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1865 IF location.postcode is not null THEN
1866 NEW.postcode = location.postcode;
1869 address_havelevel[location.rank_address] := true;
1870 IF NOT location.isguess THEN
1871 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1874 IF location.rank_address > parent_place_id_rank THEN
1875 NEW.parent_place_id = location.place_id;
1876 parent_place_id_rank = location.rank_address;
1881 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1886 --DEBUG: RAISE WARNING 'address computed';
1888 -- try using the isin value to find parent places
1889 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1890 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1891 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1892 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1894 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1896 --RAISE WARNING ' ISIN: %',location;
1898 IF location.rank_search > 4 THEN
1899 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1900 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1901 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1902 IF NEW.postcode is null AND location.postcode is not null
1903 AND NOT address_havelevel[location.rank_address] THEN
1904 NEW.postcode := location.postcode;
1907 address_havelevel[location.rank_address] := true;
1909 IF location.rank_address > parent_place_id_rank THEN
1910 NEW.parent_place_id = location.place_id;
1911 parent_place_id_rank = location.rank_address;
1920 --DEBUG: RAISE WARNING 'isin tokens processed';
1922 -- for long ways we should add search terms for the entire length
1923 IF st_length(NEW.geometry) > 0.05 THEN
1925 location_rank_search := 0;
1926 location_distance := 0;
1928 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1930 IF location.rank_address != location_rank_search THEN
1931 location_rank_search := location.rank_address;
1932 location_distance := location.distance * 1.5;
1935 IF location.rank_search > 4 AND location.distance < location_distance THEN
1937 -- Add it to the list of search terms
1938 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1939 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1940 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1947 --DEBUG: RAISE WARNING 'search terms for long ways added';
1949 IF NEW.address is not null AND NEW.address ? 'postcode'
1950 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1951 NEW.postcode := NEW.address->'postcode';
1954 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1955 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1958 -- if we have a name add this to the name search table
1959 IF NEW.name IS NOT NULL THEN
1961 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1962 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1963 --DEBUG: RAISE WARNING 'added to location (full)';
1966 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1967 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1968 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1971 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
1972 --DEBUG: RAISE WARNING 'added to serach name (full)';
1976 -- If we've not managed to pick up a better one - default centroid
1977 IF NEW.centroid IS NULL THEN
1978 NEW.centroid := place_centroid;
1981 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1988 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1994 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1996 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1997 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1998 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1999 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
2001 IF OLD.rank_address < 30 THEN
2003 -- mark everything linked to this place for re-indexing
2004 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
2005 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
2006 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
2008 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
2009 DELETE FROM place_addressline where address_place_id = OLD.place_id;
2011 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
2012 b := deleteRoad(OLD.partition, OLD.place_id);
2014 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
2015 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
2016 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
2017 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
2018 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
2022 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2024 IF OLD.rank_address < 26 THEN
2025 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2028 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2030 IF OLD.name is not null THEN
2031 b := deleteSearchName(OLD.partition, OLD.place_id);
2034 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2036 DELETE FROM place_addressline where place_id = OLD.place_id;
2038 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2040 -- remove from tables for special search
2041 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2042 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2044 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2047 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2055 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2061 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2063 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2064 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2065 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;
2067 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2073 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;
2075 -- interpolations are special
2076 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2077 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2086 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2091 existingplacex RECORD;
2092 existingline RECORD;
2093 existinggeometry GEOMETRY;
2094 existingplace_id BIGINT;
2099 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2100 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2101 -- filter wrong tupels
2102 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
2103 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2104 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2105 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2109 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2110 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2111 -- Have we already done this place?
2112 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;
2114 -- Get the existing place_id
2115 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2117 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2118 IF existing.osm_type IS NULL THEN
2119 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2122 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2123 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2125 -- 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)
2126 IF existingline.osm_id IS NOT NULL THEN
2127 delete from location_property_osmline where osm_id = NEW.osm_id;
2130 -- for interpolations invalidate all nodes on the line
2131 update placex p set indexed_status = 2
2132 from planet_osm_ways w
2133 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2136 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2137 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2140 IF existing.osm_type IS NULL THEN
2144 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2145 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2146 OR existing.geometry::text != NEW.geometry::text
2151 address = NEW.address,
2152 extratags = NEW.extratags,
2153 admin_level = NEW.admin_level,
2154 geometry = NEW.geometry
2155 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2160 ELSE -- insert to placex
2162 -- Patch in additional country names
2163 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2164 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2165 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2166 IF existing.name IS NOT NULL THEN
2167 NEW.name = existing.name || NEW.name;
2171 -- Have we already done this place?
2172 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;
2174 -- Get the existing place_id
2175 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;
2177 -- Handle a place changing type by removing the old data
2178 -- My generated 'place' types are causing havok because they overlap with real keys
2179 -- TODO: move them to their own special purpose key/class to avoid collisions
2180 IF existing.osm_type IS NULL THEN
2181 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2184 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2185 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2188 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2189 AND st_area(existing.geometry) > 0.02
2190 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2191 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2193 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2194 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2195 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2199 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2200 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2202 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2203 IF existingplacex.osm_type IS NULL OR
2204 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2207 IF existingplacex.osm_type IS NOT NULL THEN
2208 -- sanity check: ignore admin_level changes on places with too many active children
2209 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2210 --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;
2211 --LIMIT INDEXING: IF i > 100000 THEN
2212 --LIMIT INDEXING: RETURN null;
2213 --LIMIT INDEXING: END IF;
2216 IF existing.osm_type IS NOT NULL THEN
2217 -- pathological case caused by the triggerless copy into place during initial import
2218 -- force delete even for large areas, it will be reinserted later
2219 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;
2220 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2223 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2224 insert into placex (osm_type, osm_id, class, type, name,
2225 admin_level, address, extratags, geometry)
2226 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2227 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2229 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2234 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2235 IF existing.geometry::text != NEW.geometry::text
2236 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2237 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2240 -- Get the version of the geometry actually used (in placex table)
2241 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;
2243 -- Performance limit
2244 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2246 -- 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
2247 update placex set indexed_status = 2 where indexed_status = 0 and
2248 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2249 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2250 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2252 update placex set indexed_status = 2 where indexed_status = 0 and
2253 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2254 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2255 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2262 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2263 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2264 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2265 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2266 OR existing.geometry::text != NEW.geometry::text
2271 address = NEW.address,
2272 extratags = NEW.extratags,
2273 admin_level = NEW.admin_level,
2274 geometry = NEW.geometry
2275 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2278 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2279 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2280 -- postcode was deleted, no longer retain in placex
2281 DELETE FROM placex where place_id = existingplacex.place_id;
2285 NEW.name := hstore('ref', NEW.address->'postcode');
2288 IF NEW.class in ('boundary')
2289 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2290 DELETE FROM placex where place_id = existingplacex.place_id;
2296 address = NEW.address,
2297 parent_place_id = null,
2298 extratags = NEW.extratags,
2299 admin_level = NEW.admin_level,
2301 geometry = NEW.geometry
2302 where place_id = existingplacex.place_id;
2304 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2305 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2306 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2307 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2308 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);
2311 -- linked places should get potential new naming and addresses
2312 IF existingplacex.linked_place_id is not NULL THEN
2315 extratags = p.extratags,
2318 where x.place_id = existingplacex.linked_place_id
2319 and x.indexed_status = 0
2320 and x.osm_type = p.osm_type
2321 and x.osm_id = p.osm_id
2322 and x.class = p.class;
2327 -- Abort the add (we modified the existing place instead)
2332 $$ LANGUAGE plpgsql;
2335 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2340 IF name is null THEN
2344 FOR j IN 1..array_upper(languagepref,1) LOOP
2345 IF name ? languagepref[j] THEN
2346 result := trim(name->languagepref[j]);
2347 IF result != '' THEN
2353 -- anything will do as a fallback - just take the first name type thing there is
2354 RETURN trim((avals(name))[1]);
2357 LANGUAGE plpgsql IMMUTABLE;
2359 --housenumber only needed for tiger data
2360 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2372 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2373 currresult := trim(get_name_by_language(location.name, languagepref));
2374 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2375 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2376 prevresult := currresult;
2380 RETURN array_to_string(result,', ');
2385 DROP TYPE IF EXISTS addressline CASCADE;
2386 create type addressline as (
2393 admin_level INTEGER,
2396 rank_address INTEGER,
2400 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2403 for_place_id BIGINT;
2408 countrylocation RECORD;
2409 searchcountrycode varchar(2);
2410 searchhousenumber TEXT;
2411 searchhousename HSTORE;
2412 searchrankaddress INTEGER;
2413 searchpostcode TEXT;
2419 -- first query osmline (interpolation lines)
2420 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2421 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2422 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2423 IF for_place_id IS NOT NULL THEN
2424 searchhousenumber = in_housenumber::text;
2427 --then query tiger data
2428 -- %NOTIGERDATA% IF 0 THEN
2429 IF for_place_id IS NULL THEN
2430 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2431 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2432 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2433 IF for_place_id IS NOT NULL THEN
2434 searchhousenumber = in_housenumber::text;
2437 -- %NOTIGERDATA% END IF;
2439 -- %NOAUXDATA% IF 0 THEN
2440 IF for_place_id IS NULL THEN
2441 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2442 WHERE place_id = in_place_id
2443 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2445 -- %NOAUXDATA% END IF;
2448 IF for_place_id IS NULL THEN
2449 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2450 FROM location_postcode
2451 WHERE place_id = in_place_id
2452 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2455 IF for_place_id IS NULL THEN
2456 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2457 WHERE place_id = in_place_id and rank_search > 27
2458 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2461 IF for_place_id IS NULL THEN
2462 select coalesce(linked_place_id, place_id), country_code,
2463 housenumber, rank_search, postcode, null
2464 from placex where place_id = in_place_id
2465 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2468 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2471 hadcountry := false;
2473 select placex.place_id, osm_type, osm_id, name,
2474 class, type, admin_level, true as isaddress,
2475 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2476 0 as distance, country_code, postcode
2478 where place_id = for_place_id
2480 --RAISE WARNING '%',location;
2481 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2482 searchcountrycode := location.country_code;
2484 IF location.type in ('postcode', 'postal_code') THEN
2485 location.isaddress := FALSE;
2486 ELSEIF location.rank_address = 4 THEN
2489 IF location.rank_address < 4 AND NOT hadcountry THEN
2490 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2491 IF countryname IS NOT NULL THEN
2492 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2493 RETURN NEXT countrylocation;
2496 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2497 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2498 location.distance)::addressline;
2499 RETURN NEXT countrylocation;
2500 found := location.rank_address;
2504 select placex.place_id, osm_type, osm_id, name,
2505 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2506 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2507 admin_level, fromarea, isaddress,
2508 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,
2509 distance,country_code,postcode
2510 from place_addressline join placex on (address_place_id = placex.place_id)
2511 where place_addressline.place_id = for_place_id
2512 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2513 and address_place_id != for_place_id
2514 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2515 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2517 --RAISE WARNING '%',location;
2518 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2519 searchcountrycode := location.country_code;
2521 IF location.type in ('postcode', 'postal_code') THEN
2522 location.isaddress := FALSE;
2524 IF location.rank_address = 4 AND location.isaddress THEN
2527 IF location.rank_address < 4 AND NOT hadcountry THEN
2528 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2529 IF countryname IS NOT NULL THEN
2530 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2531 RETURN NEXT countrylocation;
2534 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2535 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2536 location.distance)::addressline;
2537 RETURN NEXT countrylocation;
2538 found := location.rank_address;
2542 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2543 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2544 IF countryname IS NOT NULL THEN
2545 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2546 RETURN NEXT location;
2550 IF searchcountrycode IS NOT NULL THEN
2551 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2552 RETURN NEXT location;
2555 IF searchhousename IS NOT NULL THEN
2556 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2557 RETURN NEXT location;
2560 IF searchhousenumber IS NOT NULL THEN
2561 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2562 RETURN NEXT location;
2565 IF searchpostcode IS NOT NULL THEN
2566 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2567 RETURN NEXT location;
2576 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2582 ELSEIF rank < 4 THEN
2584 ELSEIF rank < 8 THEN
2586 ELSEIF rank < 12 THEN
2588 ELSEIF rank < 16 THEN
2590 ELSEIF rank = 16 THEN
2592 ELSEIF rank = 17 THEN
2593 RETURN 'Town / Island';
2594 ELSEIF rank = 18 THEN
2595 RETURN 'Village / Hamlet';
2596 ELSEIF rank = 20 THEN
2598 ELSEIF rank = 21 THEN
2599 RETURN 'Postcode Area';
2600 ELSEIF rank = 22 THEN
2601 RETURN 'Croft / Farm / Locality / Islet';
2602 ELSEIF rank = 23 THEN
2603 RETURN 'Postcode Area';
2604 ELSEIF rank = 25 THEN
2605 RETURN 'Postcode Point';
2606 ELSEIF rank = 26 THEN
2607 RETURN 'Street / Major Landmark';
2608 ELSEIF rank = 27 THEN
2609 RETURN 'Minory Street / Path';
2610 ELSEIF rank = 28 THEN
2611 RETURN 'House / Building';
2613 RETURN 'Other: '||rank;
2620 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2626 ELSEIF rank < 2 THEN
2628 ELSEIF rank < 4 THEN
2630 ELSEIF rank = 5 THEN
2632 ELSEIF rank < 8 THEN
2634 ELSEIF rank < 12 THEN
2636 ELSEIF rank < 16 THEN
2638 ELSEIF rank = 16 THEN
2640 ELSEIF rank = 17 THEN
2641 RETURN 'Town / Village / Hamlet';
2642 ELSEIF rank = 20 THEN
2644 ELSEIF rank = 21 THEN
2645 RETURN 'Postcode Area';
2646 ELSEIF rank = 22 THEN
2647 RETURN 'Croft / Farm / Locality / Islet';
2648 ELSEIF rank = 23 THEN
2649 RETURN 'Postcode Area';
2650 ELSEIF rank = 25 THEN
2651 RETURN 'Postcode Point';
2652 ELSEIF rank = 26 THEN
2653 RETURN 'Street / Major Landmark';
2654 ELSEIF rank = 27 THEN
2655 RETURN 'Minory Street / Path';
2656 ELSEIF rank = 28 THEN
2657 RETURN 'House / Building';
2659 RETURN 'Other: '||rank;
2666 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2667 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2672 place_centroid GEOMETRY;
2673 out_partition INTEGER;
2674 out_parent_place_id BIGINT;
2676 address_street_word_id INTEGER;
2681 place_centroid := ST_Centroid(pointgeo);
2682 out_partition := get_partition(in_countrycode);
2683 out_parent_place_id := null;
2685 address_street_word_id := get_name_id(make_standard_name(in_street));
2686 IF address_street_word_id IS NOT NULL THEN
2687 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2688 out_parent_place_id := location.place_id;
2692 IF out_parent_place_id IS NULL THEN
2693 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2694 out_parent_place_id := location.place_id;
2698 out_postcode := in_postcode;
2699 IF out_postcode IS NULL THEN
2700 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2702 -- XXX look into postcode table
2705 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2706 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2707 newpoints := newpoints + 1;
2714 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2721 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2722 IF members[i+1] = member THEN
2723 result := result || members[i];
2732 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2738 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2739 IF members[i+1] = ANY(memberLabels) THEN
2740 RETURN NEXT members[i];
2749 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2750 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2752 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2753 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
2754 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2755 ), '') AS bytea), 'UTF8');
2757 LANGUAGE SQL IMMUTABLE STRICT;
2759 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2763 RETURN decode_url_part(p);
2765 WHEN others THEN return null;
2768 LANGUAGE plpgsql IMMUTABLE;
2770 DROP TYPE wikipedia_article_match CASCADE;
2771 create type wikipedia_article_match as (
2777 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2783 wiki_article_title TEXT;
2784 wiki_article_language TEXT;
2785 result wikipedia_article_match;
2787 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'];
2789 WHILE langs[i] IS NOT NULL LOOP
2790 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2791 IF wiki_article is not null THEN
2792 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2793 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2794 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2795 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2796 wiki_article := replace(wiki_article,' ','_');
2797 IF strpos(wiki_article, ':') IN (3,4) THEN
2798 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2799 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2801 wiki_article_title := trim(wiki_article);
2802 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;
2805 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2806 from wikipedia_article
2807 where language = wiki_article_language and
2808 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2810 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2811 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2812 where wikipedia_redirect.language = wiki_article_language and
2813 (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'\\',''))
2814 order by importance desc limit 1 INTO result;
2816 IF result.language is not null THEN
2827 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2828 RETURNS SETOF GEOMETRY
2842 remainingdepth INTEGER;
2847 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2849 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2850 RETURN NEXT geometry;
2854 remainingdepth := maxdepth - 1;
2855 area := ST_AREA(geometry);
2856 IF remainingdepth < 1 OR area < maxarea THEN
2857 RETURN NEXT geometry;
2861 xmin := st_xmin(geometry);
2862 xmax := st_xmax(geometry);
2863 ymin := st_ymin(geometry);
2864 ymax := st_ymax(geometry);
2865 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2867 -- if the geometry completely covers the box don't bother to slice any more
2868 IF ST_AREA(secbox) = area THEN
2869 RETURN NEXT geometry;
2873 xmid := (xmin+xmax)/2;
2874 ymid := (ymin+ymax)/2;
2877 FOR seg IN 1..4 LOOP
2880 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2883 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2886 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2889 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2892 IF st_intersects(geometry, secbox) THEN
2893 secgeo := st_intersection(geometry, secbox);
2894 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2895 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2896 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2898 RETURN NEXT geo.geom;
2910 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2911 RETURNS SETOF GEOMETRY
2916 -- 10000000000 is ~~ 1x1 degree
2917 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2918 RETURN NEXT geo.geom;
2926 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2930 osmtype character(1);
2934 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2935 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2936 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2937 -- force delete from place/placex by making it a very small geometry
2938 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;
2939 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2946 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2954 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2955 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2956 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2957 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2958 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2959 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2960 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 address ? 'place'));
2961 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2962 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 address ? 'place'));
2968 ELSEIF rank < 18 THEN
2970 ELSEIF rank < 20 THEN
2972 ELSEIF rank = 21 THEN
2974 ELSEIF rank < 24 THEN
2976 ELSEIF rank < 26 THEN
2977 diameter := 0.002; -- 100 to 200 meters
2978 ELSEIF rank < 28 THEN
2979 diameter := 0.001; -- 50 to 100 meters
2981 IF diameter > 0 THEN
2983 -- roads may cause reparenting for >27 rank places
2984 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2985 ELSEIF rank >= 16 THEN
2986 -- up to rank 16, street-less addresses may need reparenting
2987 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 address ? 'place');
2989 -- for all other places the search terms may change as well
2990 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);