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
325 SELECT postcode FROM location_postcode
326 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
327 AND location_postcode.country_code = country
328 ORDER BY ST_Distance(geom, location_postcode.geometry)
331 RETURN item.postcode;
340 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
349 FOR item IN SELECT (each(src)).* LOOP
351 s := make_standard_name(item.value);
352 w := getorcreate_country(s, lookup_country_code);
354 words := regexp_split_to_array(item.value, E'[,;()]');
355 IF array_upper(words, 1) != 1 THEN
356 FOR j IN 1..array_upper(words, 1) LOOP
357 s := make_standard_name(words[j]);
359 w := getorcreate_country(s, lookup_country_code);
368 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
378 result := '{}'::INTEGER[];
380 FOR item IN SELECT (each(src)).* LOOP
382 s := make_standard_name(item.value);
384 w := getorcreate_name_id(s, item.value);
386 IF not(ARRAY[w] <@ result) THEN
387 result := result || w;
390 w := getorcreate_word_id(s);
392 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
393 result := result || w;
396 words := string_to_array(s, ' ');
397 IF array_upper(words, 1) IS NOT NULL THEN
398 FOR j IN 1..array_upper(words, 1) LOOP
399 IF (words[j] != '') THEN
400 w = getorcreate_word_id(words[j]);
401 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
402 result := result || w;
408 words := regexp_split_to_array(item.value, E'[,;()]');
409 IF array_upper(words, 1) != 1 THEN
410 FOR j IN 1..array_upper(words, 1) LOOP
411 s := make_standard_name(words[j]);
413 w := getorcreate_word_id(s);
414 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
415 result := result || w;
421 s := regexp_replace(item.value, '市$', '');
422 IF s != item.value THEN
423 s := make_standard_name(s);
425 w := getorcreate_name_id(s, item.value);
426 IF NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
437 LANGUAGE plpgsql IMMUTABLE;
439 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
449 result := '{}'::INTEGER[];
451 s := make_standard_name(src);
452 w := getorcreate_name_id(s, src);
454 IF NOT (ARRAY[w] <@ result) THEN
455 result := result || w;
458 w := getorcreate_word_id(s);
460 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
461 result := result || w;
464 words := string_to_array(s, ' ');
465 IF array_upper(words, 1) IS NOT NULL THEN
466 FOR j IN 1..array_upper(words, 1) LOOP
467 IF (words[j] != '') THEN
468 w = getorcreate_word_id(words[j]);
469 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
470 result := result || w;
476 words := regexp_split_to_array(src, E'[,;()]');
477 IF array_upper(words, 1) != 1 THEN
478 FOR j IN 1..array_upper(words, 1) LOOP
479 s := make_standard_name(words[j]);
481 w := getorcreate_word_id(s);
482 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
483 result := result || w;
489 s := regexp_replace(src, '市$', '');
491 s := make_standard_name(s);
493 w := getorcreate_name_id(s, src);
494 IF NOT (ARRAY[w] <@ result) THEN
495 result := result || w;
503 LANGUAGE plpgsql IMMUTABLE;
505 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
508 place_centre GEOMETRY;
511 place_centre := ST_PointOnSurface(place);
513 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
515 -- Try for a OSM polygon
516 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
518 RETURN nearcountry.country_code;
521 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
523 -- Try for OSM fallback data
524 -- The order is to deal with places like HongKong that are 'states' within another polygon
525 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
527 RETURN nearcountry.country_code;
530 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
532 -- Natural earth data
533 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
535 RETURN nearcountry.country_code;
538 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
541 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
543 RETURN nearcountry.country_code;
546 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
548 -- Natural earth data
549 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
551 RETURN nearcountry.country_code;
557 LANGUAGE plpgsql IMMUTABLE;
559 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
564 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
566 RETURN lower(nearcountry.country_default_language_code);
571 LANGUAGE plpgsql IMMUTABLE;
573 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
578 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
580 RETURN lower(nearcountry.country_default_language_codes);
585 LANGUAGE plpgsql IMMUTABLE;
587 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
592 FOR nearcountry IN select partition from country_name where country_code = in_country_code
594 RETURN nearcountry.partition;
599 LANGUAGE plpgsql IMMUTABLE;
601 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
605 DELETE FROM location_area where place_id = OLD_place_id;
606 -- TODO:location_area
612 CREATE OR REPLACE FUNCTION add_location(
614 country_code varchar(2),
618 rank_address INTEGER,
634 IF rank_search > 25 THEN
635 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
638 x := deleteLocationArea(partition, place_id, rank_search);
640 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
642 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
643 postcode := upper(trim (in_postcode));
646 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
647 centroid := ST_Centroid(geometry);
649 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
650 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
656 IF rank_address = 0 THEN
658 ELSEIF rank_search <= 14 THEN
660 ELSEIF rank_search <= 15 THEN
662 ELSEIF rank_search <= 16 THEN
664 ELSEIF rank_search <= 17 THEN
666 ELSEIF rank_search <= 21 THEN
668 ELSEIF rank_search = 25 THEN
672 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
674 secgeo := ST_Buffer(geometry, diameter);
675 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
685 -- find the parent road of the cut road parts
686 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
687 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
692 parent_place_id BIGINT;
693 address_street_word_ids INTEGER[];
699 addr_street = street;
702 IF addr_street is null and addr_place is null THEN
703 select nodes from planet_osm_ways where id = wayid INTO waynodes;
704 FOR location IN SELECT placex.address from placex
705 where osm_type = 'N' and osm_id = ANY(waynodes)
706 and placex.address is not null
707 and (placex.address ? 'street' or placex.address ? 'place')
708 and indexed_status < 100
710 addr_street = location.address->'street';
711 addr_place = location.address->'place';
715 IF addr_street IS NOT NULL THEN
716 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
717 IF address_street_word_ids IS NOT NULL THEN
718 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
719 parent_place_id := location.place_id;
724 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
725 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
726 IF address_street_word_ids IS NOT NULL THEN
727 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
728 parent_place_id := location.place_id;
733 IF parent_place_id is null THEN
734 FOR location IN SELECT place_id FROM placex
735 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
736 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
737 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
738 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
740 parent_place_id := location.place_id;
744 IF parent_place_id is null THEN
748 RETURN parent_place_id;
754 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
757 NEW.place_id := nextval('seq_place');
758 NEW.indexed_date := now();
760 IF NEW.indexed_status IS NULL THEN
761 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
762 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
763 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
767 NEW.indexed_status := 1; --STATUS_NEW
768 NEW.country_code := lower(get_country_code(NEW.linegeo));
770 NEW.partition := get_partition(NEW.country_code);
771 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
780 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
786 country_code VARCHAR(2);
787 default_language VARCHAR(10);
792 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
794 NEW.place_id := nextval('seq_place');
795 NEW.indexed_status := 1; --STATUS_NEW
797 NEW.country_code := lower(get_country_code(NEW.geometry));
799 NEW.partition := get_partition(NEW.country_code);
800 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
802 -- copy 'name' to or from the default language (if there is a default language)
803 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
804 default_language := get_country_language_code(NEW.country_code);
805 IF default_language IS NOT NULL THEN
806 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
807 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
808 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
809 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
814 IF NEW.osm_type = 'X' THEN
815 -- E'X'ternal records should already be in the right format so do nothing
817 NEW.rank_search := 30;
818 NEW.rank_address := NEW.rank_search;
820 -- By doing in postgres we have the country available to us - currently only used for postcode
821 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
823 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
824 -- most likely just a part of a multipolygon postcode boundary, throw it away
828 NEW.name := hstore('ref', NEW.address->'postcode');
830 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
831 INTO NEW.rank_search, NEW.rank_address;
833 ELSEIF NEW.class = 'place' THEN
834 IF NEW.type in ('continent') THEN
835 NEW.rank_search := 2;
836 NEW.rank_address := NEW.rank_search;
837 NEW.country_code := NULL;
838 ELSEIF NEW.type in ('sea') THEN
839 NEW.rank_search := 2;
840 NEW.rank_address := 0;
841 NEW.country_code := NULL;
842 ELSEIF NEW.type in ('country') THEN
843 NEW.rank_search := 4;
844 NEW.rank_address := NEW.rank_search;
845 ELSEIF NEW.type in ('state') THEN
846 NEW.rank_search := 8;
847 NEW.rank_address := NEW.rank_search;
848 ELSEIF NEW.type in ('region') THEN
849 NEW.rank_search := 18; -- dropped from previous value of 10
850 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
851 ELSEIF NEW.type in ('county') THEN
852 NEW.rank_search := 12;
853 NEW.rank_address := NEW.rank_search;
854 ELSEIF NEW.type in ('city') THEN
855 NEW.rank_search := 16;
856 NEW.rank_address := NEW.rank_search;
857 ELSEIF NEW.type in ('island') THEN
858 NEW.rank_search := 17;
859 NEW.rank_address := 0;
860 ELSEIF NEW.type in ('town') THEN
861 NEW.rank_search := 18;
862 NEW.rank_address := 16;
863 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
864 NEW.rank_search := 19;
865 NEW.rank_address := 16;
866 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
867 NEW.rank_search := 20;
868 NEW.rank_address := NEW.rank_search;
869 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
870 NEW.rank_search := 20;
871 NEW.rank_address := 0;
872 -- Irish townlands, tagged as place=locality and locality=townland
873 IF (NEW.extratags -> 'locality') = 'townland' THEN
874 NEW.rank_address := 20;
876 ELSEIF NEW.type in ('neighbourhood') THEN
877 NEW.rank_search := 22;
878 NEW.rank_address := 22;
879 ELSEIF NEW.type in ('house','building') THEN
880 NEW.rank_search := 30;
881 NEW.rank_address := NEW.rank_search;
882 ELSEIF NEW.type in ('houses') THEN
883 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
884 NEW.rank_search := 28;
885 NEW.rank_address := 0;
888 ELSEIF NEW.class = 'boundary' THEN
889 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
890 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
893 NEW.rank_search := NEW.admin_level * 2;
894 IF NEW.type = 'administrative' THEN
895 NEW.rank_address := NEW.rank_search;
897 NEW.rank_address := 0;
899 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
900 NEW.rank_search := 22;
901 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
902 NEW.rank_address := NEW.rank_search;
904 NEW.rank_address := 0;
906 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
907 NEW.rank_search := 18;
908 NEW.rank_address := 0;
909 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
910 NEW.rank_search := 4;
911 NEW.rank_address := NEW.rank_search;
912 -- any feature more than 5 square miles is probably worth indexing
913 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
914 NEW.rank_search := 22;
915 NEW.rank_address := 0;
916 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
918 ELSEIF NEW.class = 'waterway' THEN
919 IF NEW.osm_type = 'R' THEN
920 NEW.rank_search := 16;
922 NEW.rank_search := 17;
924 NEW.rank_address := 0;
925 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
926 NEW.rank_search := 27;
927 NEW.rank_address := NEW.rank_search;
928 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
929 NEW.rank_search := 26;
930 NEW.rank_address := NEW.rank_search;
931 ELSEIF NEW.class = 'mountain_pass' THEN
932 NEW.rank_search := 20;
933 NEW.rank_address := 0;
938 IF NEW.rank_search > 30 THEN
939 NEW.rank_search := 30;
942 IF NEW.rank_address > 30 THEN
943 NEW.rank_address := 30;
946 IF (NEW.extratags -> 'capital') = 'yes' THEN
947 NEW.rank_search := NEW.rank_search - 1;
950 -- a country code make no sense below rank 4 (country)
951 IF NEW.rank_search < 4 THEN
952 NEW.country_code := NULL;
955 -- Block import below rank 22
956 -- IF NEW.rank_search > 22 THEN
960 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
962 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
964 IF NEW.rank_address > 0 THEN
965 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
966 -- Performance: We just can't handle re-indexing for country level changes
967 IF st_area(NEW.geometry) < 1 THEN
968 -- mark items within the geometry for re-indexing
969 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
971 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
972 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
973 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'));
974 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
975 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'));
978 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
980 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
981 IF NEW.type='postcode' THEN
983 ELSEIF NEW.rank_search < 16 THEN
985 ELSEIF NEW.rank_search < 18 THEN
987 ELSEIF NEW.rank_search < 20 THEN
989 ELSEIF NEW.rank_search = 21 THEN
991 ELSEIF NEW.rank_search < 24 THEN
993 ELSEIF NEW.rank_search < 26 THEN
994 diameter := 0.002; -- 100 to 200 meters
995 ELSEIF NEW.rank_search < 28 THEN
996 diameter := 0.001; -- 50 to 100 meters
999 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1000 IF NEW.rank_search >= 26 THEN
1001 -- roads may cause reparenting for >27 rank places
1002 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
1003 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1004 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
1005 ELSEIF NEW.rank_search >= 16 THEN
1006 -- up to rank 16, street-less addresses may need reparenting
1007 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');
1009 -- for all other places the search terms may change as well
1010 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);
1017 -- add to tables for special search
1018 -- Note: won't work on initial import because the classtype tables
1019 -- do not yet exist. It won't hurt either.
1020 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1021 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
1023 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1024 USING NEW.place_id, ST_Centroid(NEW.geometry);
1033 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1037 place_centroid GEOMETRY;
1041 startnumber INTEGER;
1046 sectiongeo GEOMETRY;
1047 interpol_postcode TEXT;
1051 IF OLD.indexed_status = 100 THEN
1052 delete from location_property_osmline where place_id = OLD.place_id;
1056 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1060 NEW.interpolationtype = NEW.address->'interpolation';
1062 place_centroid := ST_PointOnSurface(NEW.linegeo);
1063 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1064 NEW.address->'place',
1065 NEW.partition, place_centroid, NEW.linegeo);
1067 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1068 interpol_postcode := NEW.address->'postcode';
1069 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1071 interpol_postcode := NULL;
1074 -- if the line was newly inserted, split the line as necessary
1075 IF OLD.indexed_status = 1 THEN
1076 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1078 IF array_upper(waynodes, 1) IS NULL THEN
1082 linegeo := NEW.linegeo;
1083 startnumber := NULL;
1085 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1087 select osm_id, address, geometry
1088 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1089 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1090 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1091 IF nextnode.osm_id IS NOT NULL THEN
1092 --RAISE NOTICE 'place_id is not null';
1093 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1094 -- Make sure that the point is actually on the line. That might
1095 -- be a bit paranoid but ensures that the algorithm still works
1096 -- should osm2pgsql attempt to repair geometries.
1097 splitline := split_line_on_node(linegeo, nextnode.geometry);
1098 sectiongeo := ST_GeometryN(splitline, 1);
1099 linegeo := ST_GeometryN(splitline, 2);
1101 sectiongeo = linegeo;
1103 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1105 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1106 AND startnumber != endnumber
1107 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1109 IF (startnumber > endnumber) THEN
1110 housenum := endnumber;
1111 endnumber := startnumber;
1112 startnumber := housenum;
1113 sectiongeo := ST_Reverse(sectiongeo);
1116 -- determine postcode
1117 postcode := coalesce(interpol_postcode,
1118 prevnode.address->'postcode',
1119 nextnode.address->'postcode',
1122 IF postcode is NULL THEN
1123 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1125 IF postcode is NULL THEN
1126 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1129 IF NEW.startnumber IS NULL THEN
1130 NEW.startnumber := startnumber;
1131 NEW.endnumber := endnumber;
1132 NEW.linegeo := sectiongeo;
1133 NEW.postcode := postcode;
1135 insert into location_property_osmline
1136 (linegeo, partition, osm_id, parent_place_id,
1137 startnumber, endnumber, interpolationtype,
1138 address, postcode, country_code,
1139 geometry_sector, indexed_status)
1140 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1141 startnumber, endnumber, NEW.interpolationtype,
1142 NEW.address, postcode,
1143 NEW.country_code, NEW.geometry_sector, 0);
1147 -- early break if we are out of line string,
1148 -- might happen when a line string loops back on itself
1149 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1153 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1154 prevnode := nextnode;
1159 -- marking descendants for reparenting is not needed, because there are
1160 -- actually no descendants for interpolation lines
1166 -- Trigger for updates of location_postcode
1168 -- Computes the parent object the postcode most likely refers to.
1169 -- This will be the place that determines the address displayed when
1170 -- searching for this postcode.
1171 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1178 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1182 NEW.indexed_date = now();
1184 partition := get_partition(NEW.country_code);
1186 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1187 INTO NEW.rank_search, NEW.rank_address;
1189 NEW.parent_place_id = 0;
1192 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1193 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1195 NEW.parent_place_id = location.place_id;
1203 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1208 place_centroid GEOMETRY;
1210 search_maxdistance FLOAT[];
1211 search_mindistance FLOAT[];
1212 address_havelevel BOOLEAN[];
1219 relation_members TEXT[];
1221 linkedplacex RECORD;
1222 search_diameter FLOAT;
1223 search_prevdiameter FLOAT;
1224 search_maxrank INTEGER;
1225 address_maxrank INTEGER;
1226 address_street_word_id INTEGER;
1227 address_street_word_ids INTEGER[];
1228 parent_place_id_rank BIGINT;
1236 location_rank_search INTEGER;
1237 location_distance FLOAT;
1238 location_parent GEOMETRY;
1239 location_isaddress BOOLEAN;
1240 location_keywords INTEGER[];
1242 default_language TEXT;
1243 name_vector INTEGER[];
1244 nameaddress_vector INTEGER[];
1246 linked_node_id BIGINT;
1247 linked_importance FLOAT;
1248 linked_wikipedia TEXT;
1253 IF OLD.indexed_status = 100 THEN
1254 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1255 delete from placex where place_id = OLD.place_id;
1259 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1263 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1265 NEW.indexed_date = now();
1267 result := deleteSearchName(NEW.partition, NEW.place_id);
1268 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1269 result := deleteRoad(NEW.partition, NEW.place_id);
1270 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1271 UPDATE placex set linked_place_id = null, indexed_status = 2
1272 where linked_place_id = NEW.place_id;
1273 -- update not necessary for osmline, cause linked_place_id does not exist
1275 IF NEW.linked_place_id is not null THEN
1276 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1280 --DEBUG: RAISE WARNING 'Copy over address tags';
1281 IF NEW.address is not NULL THEN
1282 IF NEW.address ? 'conscriptionnumber' THEN
1283 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1284 IF NEW.address ? 'streetnumber' THEN
1285 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1286 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1288 NEW.housenumber := NEW.address->'conscriptionnumber';
1290 ELSEIF NEW.address ? 'streetnumber' THEN
1291 NEW.housenumber := NEW.address->'streetnumber';
1292 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1293 ELSEIF NEW.address ? 'housenumber' THEN
1294 NEW.housenumber := NEW.address->'housenumber';
1295 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1298 addr_street = NEW.address->'street';
1299 addr_place = NEW.address->'place';
1301 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1302 i := getorcreate_postcode_id(NEW.address->'postcode');
1306 -- Speed up searches - just use the centroid of the feature
1307 -- cheaper but less acurate
1308 place_centroid := ST_PointOnSurface(NEW.geometry);
1309 NEW.centroid := null;
1310 NEW.postcode := null;
1311 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1313 -- recalculate country and partition
1314 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1315 -- for countries, believe the mapped country code,
1316 -- so that we remain in the right partition if the boundaries
1318 NEW.country_code := lower(NEW.address->'country');
1319 NEW.partition := get_partition(lower(NEW.country_code));
1320 IF NEW.partition = 0 THEN
1321 NEW.country_code := lower(get_country_code(place_centroid));
1322 NEW.partition := get_partition(NEW.country_code);
1325 IF NEW.rank_search >= 4 THEN
1326 NEW.country_code := lower(get_country_code(place_centroid));
1328 NEW.country_code := NULL;
1330 NEW.partition := get_partition(NEW.country_code);
1332 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1334 -- waterway ways are linked when they are part of a relation and have the same class/type
1335 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1336 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1338 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1339 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1340 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1341 FOR linked_node_id IN SELECT place_id FROM placex
1342 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1343 and class = NEW.class and type = NEW.type
1344 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1346 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1351 --DEBUG: RAISE WARNING 'Waterway processed';
1354 -- Adding ourselves to the list simplifies address calculations later
1355 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1356 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1358 -- What level are we searching from
1359 search_maxrank := NEW.rank_search;
1361 -- Thought this wasn't needed but when we add new languages to the country_name table
1362 -- we need to update the existing names
1363 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1364 default_language := get_country_language_code(NEW.country_code);
1365 IF default_language IS NOT NULL THEN
1366 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1367 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1368 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1369 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1373 --DEBUG: RAISE WARNING 'Local names updated';
1375 -- Initialise the name vector using our name
1376 name_vector := make_keywords(NEW.name);
1377 nameaddress_vector := '{}'::int[];
1380 address_havelevel[i] := false;
1383 NEW.importance := null;
1384 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1385 IF NEW.importance IS NULL THEN
1386 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;
1389 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1391 -- ---------------------------------------------------------------------------
1392 -- For low level elements we inherit from our parent road
1393 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1395 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1397 -- We won't get a better centroid, besides these places are too small to care
1398 NEW.centroid := place_centroid;
1400 NEW.parent_place_id := null;
1402 -- if we have a POI and there is no address information,
1403 -- see if we can get it from a surrounding building
1404 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1405 AND NEW.housenumber IS NULL THEN
1406 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1407 and address is not null
1408 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1409 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1412 NEW.housenumber := location.address->'housenumber';
1413 addr_street := location.address->'street';
1414 addr_place := location.address->'place';
1415 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1419 -- We have to find our parent road.
1420 -- Copy data from linked items (points on ways, addr:street links, relations)
1422 -- Is this object part of a relation?
1423 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1425 -- At the moment we only process one type of relation - associatedStreet
1426 IF relation.tags @> ARRAY['associatedStreet'] THEN
1427 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1428 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1429 --RAISE WARNING 'node in relation %',relation;
1430 SELECT place_id from placex where osm_type = 'W'
1431 and osm_id = substring(relation.members[i],2,200)::bigint
1432 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1437 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1439 -- Note that addr:street links can only be indexed once the street itself is indexed
1440 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1441 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1442 IF address_street_word_ids IS NOT NULL THEN
1443 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1444 NEW.parent_place_id := location.place_id;
1448 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1450 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1451 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1452 IF address_street_word_ids IS NOT NULL THEN
1453 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1454 NEW.parent_place_id := location.place_id;
1458 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1460 -- Is this node part of an interpolation?
1461 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1463 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1464 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1467 NEW.parent_place_id := location.parent_place_id;
1470 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1472 -- Is this node part of a way?
1473 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1475 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
1476 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)
1478 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1480 -- Way IS a road then we are on it - that must be our road
1481 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1482 --RAISE WARNING 'node in way that is a street %',location;
1483 NEW.parent_place_id := location.place_id;
1485 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1487 -- If the way mentions a street or place address, try that for parenting.
1488 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1489 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1490 IF address_street_word_ids IS NOT NULL THEN
1491 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1492 NEW.parent_place_id := linkedplacex.place_id;
1496 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1498 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1499 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1500 IF address_street_word_ids IS NOT NULL THEN
1501 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1502 NEW.parent_place_id := linkedplacex.place_id;
1506 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1508 -- Is the WAY part of a relation
1509 IF NEW.parent_place_id IS NULL THEN
1510 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1512 -- At the moment we only process one type of relation - associatedStreet
1513 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1514 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1515 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1516 --RAISE WARNING 'node in way that is in a relation %',relation;
1517 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1518 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1524 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1530 -- Still nothing, just use the nearest road
1531 IF NEW.parent_place_id IS NULL THEN
1532 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1533 NEW.parent_place_id := location.place_id;
1536 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1539 -- If we didn't find any road fallback to standard method
1540 IF NEW.parent_place_id IS NOT NULL THEN
1542 -- Get the details of the parent road
1543 select * from search_name where place_id = NEW.parent_place_id INTO location;
1544 NEW.country_code := location.country_code;
1545 --DEBUG: RAISE WARNING 'Got parent details from search name';
1547 -- determine postcode
1548 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1549 NEW.postcode = NEW.address->'postcode';
1551 SELECT postcode FROM placex WHERE place_id = NEW.parent_place_id INTO NEW.postcode;
1553 IF NEW.postcode is null THEN
1554 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1557 -- If there is no name it isn't searchable, don't bother to create a search record
1558 IF NEW.name is NULL THEN
1559 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1563 -- Merge address from parent
1564 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1565 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1567 -- Performance, it would be more acurate to do all the rest of the import
1568 -- process but it takes too long
1569 -- Just be happy with inheriting from parent road only
1571 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1572 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1573 --DEBUG: RAISE WARNING 'Place added to location table';
1576 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);
1577 --DEBUG: RAISE WARNING 'Place added to search table';
1584 -- ---------------------------------------------------------------------------
1586 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1588 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1590 -- see if we have any special relation members
1591 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1592 --DEBUG: RAISE WARNING 'Got relation members';
1594 IF relation_members IS NOT NULL THEN
1595 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1596 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1598 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1599 and osm_id = substring(relMember.member,2,10000)::bigint
1600 and class = 'place' order by rank_search desc limit 1 LOOP
1602 -- If we don't already have one use this as the centre point of the geometry
1603 IF NEW.centroid IS NULL THEN
1604 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1607 -- merge in the label name, re-init word vector
1608 IF NOT linkedPlacex.name IS NULL THEN
1609 NEW.name := linkedPlacex.name || NEW.name;
1610 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1613 -- merge in extra tags
1614 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1616 -- mark the linked place (excludes from search results)
1617 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1619 -- keep a note of the node id in case we need it for wikipedia in a bit
1620 linked_node_id := linkedPlacex.osm_id;
1621 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1622 --DEBUG: RAISE WARNING 'Linked label member';
1627 IF NEW.centroid IS NULL THEN
1629 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1630 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1632 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1633 and osm_id = substring(relMember.member,2,10000)::bigint
1634 and class = 'place' order by rank_search desc limit 1 LOOP
1636 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1637 -- But that can be fixed by explicitly setting the label in the data
1638 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1639 AND NEW.rank_address = linkedPlacex.rank_address THEN
1641 -- If we don't already have one use this as the centre point of the geometry
1642 IF NEW.centroid IS NULL THEN
1643 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1646 -- merge in the name, re-init word vector
1647 IF NOT linkedPlacex.name IS NULL THEN
1648 NEW.name := linkedPlacex.name || NEW.name;
1649 name_vector := make_keywords(NEW.name);
1652 -- merge in extra tags
1653 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1655 -- mark the linked place (excludes from search results)
1656 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1658 -- keep a note of the node id in case we need it for wikipedia in a bit
1659 linked_node_id := linkedPlacex.osm_id;
1660 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1661 --DEBUG: RAISE WARNING 'Linked admin_center';
1673 -- Name searches can be done for ways as well as relations
1674 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1676 -- not found one yet? how about doing a name search
1677 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1679 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1680 FOR linkedPlacex IN select placex.* from placex WHERE
1681 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1682 AND placex.rank_address = NEW.rank_address
1683 AND placex.place_id != NEW.place_id
1684 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1685 AND st_covers(NEW.geometry, placex.geometry)
1687 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1688 -- If we don't already have one use this as the centre point of the geometry
1689 IF NEW.centroid IS NULL THEN
1690 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1693 -- merge in the name, re-init word vector
1694 NEW.name := linkedPlacex.name || NEW.name;
1695 name_vector := make_keywords(NEW.name);
1697 -- merge in extra tags
1698 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1700 -- mark the linked place (excludes from search results)
1701 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1703 -- keep a note of the node id in case we need it for wikipedia in a bit
1704 linked_node_id := linkedPlacex.osm_id;
1705 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1706 --DEBUG: RAISE WARNING 'Linked named place';
1710 IF NEW.centroid IS NOT NULL THEN
1711 place_centroid := NEW.centroid;
1712 -- Place might have had only a name tag before but has now received translations
1713 -- from the linked place. Make sure a name tag for the default language exists in
1715 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1716 default_language := get_country_language_code(NEW.country_code);
1717 IF default_language IS NOT NULL THEN
1718 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1719 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1720 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1721 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1725 --DEBUG: RAISE WARNING 'Names updated from linked places';
1728 -- Use the maximum importance if a one could be computed from the linked object.
1729 IF linked_importance is not null AND
1730 (NEW.importance is null or NEW.importance < linked_importance) THEN
1731 NEW.importance = linked_importance;
1734 -- Still null? how about looking it up by the node id
1735 IF NEW.importance IS NULL THEN
1736 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1737 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;
1742 -- make sure all names are in the word table
1743 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1744 perform create_country(NEW.name, lower(NEW.country_code));
1745 --DEBUG: RAISE WARNING 'Country names updated';
1748 NEW.parent_place_id = 0;
1749 parent_place_id_rank = 0;
1752 -- convert isin to array of tokenids
1753 --DEBUG: RAISE WARNING 'Starting address search';
1754 isin_tokens := '{}'::int[];
1755 IF NEW.address IS NOT NULL THEN
1756 isin := avals(NEW.address);
1757 IF array_upper(isin, 1) IS NOT NULL THEN
1758 FOR i IN 1..array_upper(isin, 1) LOOP
1759 -- TODO further split terms with comma and semicolon
1760 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1761 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1762 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1763 isin_tokens := isin_tokens || address_street_word_id;
1766 -- merge word into address vector
1767 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1768 IF address_street_word_id IS NOT NULL THEN
1769 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1775 -- %NOTIGERDATA% IF 0 THEN
1776 -- for the USA we have an additional address table. Merge in zip codes from there too
1777 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1778 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1779 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1780 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1781 isin_tokens := isin_tokens || address_street_word_id;
1783 -- also merge in the single word version
1784 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1785 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1788 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1789 -- %NOTIGERDATA% END IF;
1791 -- RAISE WARNING 'ISIN: %', isin_tokens;
1793 -- Process area matches
1794 location_rank_search := 0;
1795 location_distance := 0;
1796 location_parent := NULL;
1797 -- added ourself as address already
1798 address_havelevel[NEW.rank_address] := true;
1799 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1801 SELECT * from getNearFeatures(NEW.partition,
1802 CASE WHEN NEW.rank_search >= 26
1803 AND NEW.rank_search < 30
1805 ELSE place_centroid END,
1806 search_maxrank, isin_tokens)
1808 IF location.rank_address != location_rank_search THEN
1809 location_rank_search := location.rank_address;
1810 IF location.isguess THEN
1811 location_distance := location.distance * 1.5;
1813 IF location.rank_address <= 12 THEN
1814 -- for county and above, if we have an area consider that exact
1815 -- (It would be nice to relax the constraint for places close to
1816 -- the boundary but we'd need the exact geometry for that. Too
1818 location_distance = 0;
1820 -- Below county level remain slightly fuzzy.
1821 location_distance := location.distance * 0.5;
1825 CONTINUE WHEN location.keywords <@ location_keywords;
1828 IF location.distance < location_distance OR NOT location.isguess THEN
1829 location_keywords := location.keywords;
1831 location_isaddress := NOT address_havelevel[location.rank_address];
1832 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1833 location_isaddress := ST_Contains(location_parent,location.centroid);
1836 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1837 -- Add it to the list of search terms
1838 IF location.rank_search > 4 THEN
1839 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1841 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1842 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1844 IF location_isaddress THEN
1845 -- add postcode if we have one
1846 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1847 IF location.postcode is not null THEN
1848 NEW.postcode = location.postcode;
1851 address_havelevel[location.rank_address] := true;
1852 IF NOT location.isguess THEN
1853 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1856 IF location.rank_address > parent_place_id_rank THEN
1857 NEW.parent_place_id = location.place_id;
1858 parent_place_id_rank = location.rank_address;
1863 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1868 --DEBUG: RAISE WARNING 'address computed';
1870 -- try using the isin value to find parent places
1871 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1872 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1873 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1874 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1876 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1878 --RAISE WARNING ' ISIN: %',location;
1880 IF location.rank_search > 4 THEN
1881 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1882 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1883 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1884 IF NEW.postcode is null AND location.postcode is not null
1885 AND NOT address_havelevel[location.rank_address] THEN
1886 NEW.postcode := location.postcode;
1889 address_havelevel[location.rank_address] := true;
1891 IF location.rank_address > parent_place_id_rank THEN
1892 NEW.parent_place_id = location.place_id;
1893 parent_place_id_rank = location.rank_address;
1902 --DEBUG: RAISE WARNING 'isin tokens processed';
1904 -- for long ways we should add search terms for the entire length
1905 IF st_length(NEW.geometry) > 0.05 THEN
1907 location_rank_search := 0;
1908 location_distance := 0;
1910 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1912 IF location.rank_address != location_rank_search THEN
1913 location_rank_search := location.rank_address;
1914 location_distance := location.distance * 1.5;
1917 IF location.rank_search > 4 AND location.distance < location_distance THEN
1919 -- Add it to the list of search terms
1920 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1921 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1922 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1929 --DEBUG: RAISE WARNING 'search terms for long ways added';
1931 IF NEW.address is not null AND NEW.address ? 'postcode'
1932 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1933 NEW.postcode := NEW.address->'postcode';
1936 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1937 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1940 -- if we have a name add this to the name search table
1941 IF NEW.name IS NOT NULL THEN
1943 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1944 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1945 --DEBUG: RAISE WARNING 'added to location (full)';
1948 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1949 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1950 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1953 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);
1954 --DEBUG: RAISE WARNING 'added to serach name (full)';
1958 -- If we've not managed to pick up a better one - default centroid
1959 IF NEW.centroid IS NULL THEN
1960 NEW.centroid := place_centroid;
1963 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1970 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1976 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1978 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1979 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1980 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1981 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1983 IF OLD.rank_address < 30 THEN
1985 -- mark everything linked to this place for re-indexing
1986 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1987 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1988 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1990 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1991 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1993 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1994 b := deleteRoad(OLD.partition, OLD.place_id);
1996 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1997 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1998 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1999 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
2000 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
2004 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
2006 IF OLD.rank_address < 26 THEN
2007 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
2010 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
2012 IF OLD.name is not null THEN
2013 b := deleteSearchName(OLD.partition, OLD.place_id);
2016 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
2018 DELETE FROM place_addressline where place_id = OLD.place_id;
2020 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
2022 -- remove from tables for special search
2023 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
2024 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
2026 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
2029 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2037 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2043 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2045 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2046 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2047 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;
2049 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2055 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;
2057 -- interpolations are special
2058 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2059 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2068 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2073 existingplacex RECORD;
2074 existingline RECORD;
2075 existinggeometry GEOMETRY;
2076 existingplace_id BIGINT;
2081 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2082 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2083 -- filter wrong tupels
2084 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
2085 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2086 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2087 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2091 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2092 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2093 -- Have we already done this place?
2094 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;
2096 -- Get the existing place_id
2097 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2099 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2100 IF existing.osm_type IS NULL THEN
2101 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2104 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2105 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2107 -- 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)
2108 IF existingline.osm_id IS NOT NULL THEN
2109 delete from location_property_osmline where osm_id = NEW.osm_id;
2112 -- for interpolations invalidate all nodes on the line
2113 update placex p set indexed_status = 2
2114 from planet_osm_ways w
2115 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2118 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2119 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2122 IF existing.osm_type IS NULL THEN
2126 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2127 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2128 OR existing.geometry::text != NEW.geometry::text
2133 address = NEW.address,
2134 extratags = NEW.extratags,
2135 admin_level = NEW.admin_level,
2136 geometry = NEW.geometry
2137 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2142 ELSE -- insert to placex
2144 -- Patch in additional country names
2145 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2146 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2147 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2148 IF existing.name IS NOT NULL THEN
2149 NEW.name = existing.name || NEW.name;
2153 -- Have we already done this place?
2154 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;
2156 -- Get the existing place_id
2157 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;
2159 -- Handle a place changing type by removing the old data
2160 -- My generated 'place' types are causing havok because they overlap with real keys
2161 -- TODO: move them to their own special purpose key/class to avoid collisions
2162 IF existing.osm_type IS NULL THEN
2163 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2166 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2167 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2170 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2171 AND st_area(existing.geometry) > 0.02
2172 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2173 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2175 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2176 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2177 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2181 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2182 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2184 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2185 IF existingplacex.osm_type IS NULL OR
2186 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2189 IF existingplacex.osm_type IS NOT NULL THEN
2190 -- sanity check: ignore admin_level changes on places with too many active children
2191 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2192 --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;
2193 --LIMIT INDEXING: IF i > 100000 THEN
2194 --LIMIT INDEXING: RETURN null;
2195 --LIMIT INDEXING: END IF;
2198 IF existing.osm_type IS NOT NULL THEN
2199 -- pathological case caused by the triggerless copy into place during initial import
2200 -- force delete even for large areas, it will be reinserted later
2201 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;
2202 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2205 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2206 insert into placex (osm_type, osm_id, class, type, name,
2207 admin_level, address, extratags, geometry)
2208 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2209 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2211 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2216 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2217 IF existing.geometry::text != NEW.geometry::text
2218 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2219 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2222 -- Get the version of the geometry actually used (in placex table)
2223 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;
2225 -- Performance limit
2226 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2228 -- 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
2229 update placex set indexed_status = 2 where indexed_status = 0 and
2230 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2231 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2232 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2234 update placex set indexed_status = 2 where indexed_status = 0 and
2235 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2236 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2237 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2244 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2245 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2246 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2247 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2248 OR existing.geometry::text != NEW.geometry::text
2253 address = NEW.address,
2254 extratags = NEW.extratags,
2255 admin_level = NEW.admin_level,
2256 geometry = NEW.geometry
2257 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2260 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2261 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2262 -- postcode was deleted, no longer retain in placex
2263 DELETE FROM placex where place_id = existingplacex.place_id;
2267 NEW.name := hstore('ref', NEW.address->'postcode');
2270 IF NEW.class in ('boundary')
2271 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2272 DELETE FROM placex where place_id = existingplacex.place_id;
2278 address = NEW.address,
2279 parent_place_id = null,
2280 extratags = NEW.extratags,
2281 admin_level = NEW.admin_level,
2283 geometry = NEW.geometry
2284 where place_id = existingplacex.place_id;
2286 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2287 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2288 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2289 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2290 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);
2293 -- linked places should get potential new naming and addresses
2294 IF existingplacex.linked_place_id is not NULL THEN
2297 extratags = p.extratags,
2300 where x.place_id = existingplacex.linked_place_id
2301 and x.indexed_status = 0
2302 and x.osm_type = p.osm_type
2303 and x.osm_id = p.osm_id
2304 and x.class = p.class;
2309 -- Abort the add (we modified the existing place instead)
2314 $$ LANGUAGE plpgsql;
2317 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2322 IF name is null THEN
2326 FOR j IN 1..array_upper(languagepref,1) LOOP
2327 IF name ? languagepref[j] THEN
2328 result := trim(name->languagepref[j]);
2329 IF result != '' THEN
2335 -- anything will do as a fallback - just take the first name type thing there is
2336 RETURN trim((avals(name))[1]);
2339 LANGUAGE plpgsql IMMUTABLE;
2341 --housenumber only needed for tiger data
2342 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2354 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2355 currresult := trim(get_name_by_language(location.name, languagepref));
2356 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2357 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2358 prevresult := currresult;
2362 RETURN array_to_string(result,', ');
2367 DROP TYPE IF EXISTS addressline CASCADE;
2368 create type addressline as (
2375 admin_level INTEGER,
2378 rank_address INTEGER,
2382 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2385 for_place_id BIGINT;
2390 countrylocation RECORD;
2391 searchcountrycode varchar(2);
2392 searchhousenumber TEXT;
2393 searchhousename HSTORE;
2394 searchrankaddress INTEGER;
2395 searchpostcode TEXT;
2401 -- first query osmline (interpolation lines)
2402 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2403 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2404 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2405 IF for_place_id IS NOT NULL THEN
2406 searchhousenumber = in_housenumber::text;
2409 --then query tiger data
2410 -- %NOTIGERDATA% IF 0 THEN
2411 IF for_place_id IS NULL THEN
2412 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2413 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2414 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2415 IF for_place_id IS NOT NULL THEN
2416 searchhousenumber = in_housenumber::text;
2419 -- %NOTIGERDATA% END IF;
2421 -- %NOAUXDATA% IF 0 THEN
2422 IF for_place_id IS NULL THEN
2423 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2424 WHERE place_id = in_place_id
2425 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2427 -- %NOAUXDATA% END IF;
2430 IF for_place_id IS NULL THEN
2431 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2432 FROM location_postcode
2433 WHERE place_id = in_place_id
2434 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2437 IF for_place_id IS NULL THEN
2438 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2439 WHERE place_id = in_place_id and rank_search > 27
2440 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2443 IF for_place_id IS NULL THEN
2444 select coalesce(linked_place_id, place_id), country_code,
2445 housenumber, rank_search, postcode, null
2446 from placex where place_id = in_place_id
2447 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2450 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2453 hadcountry := false;
2455 select placex.place_id, osm_type, osm_id, name,
2456 class, type, admin_level, true as isaddress,
2457 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2458 0 as distance, country_code, postcode
2460 where place_id = for_place_id
2462 --RAISE WARNING '%',location;
2463 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2464 searchcountrycode := location.country_code;
2466 IF location.type in ('postcode', 'postal_code') THEN
2467 location.isaddress := FALSE;
2468 ELSEIF location.rank_address = 4 THEN
2471 IF location.rank_address < 4 AND NOT hadcountry THEN
2472 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2473 IF countryname IS NOT NULL THEN
2474 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2475 RETURN NEXT countrylocation;
2478 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2479 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2480 location.distance)::addressline;
2481 RETURN NEXT countrylocation;
2482 found := location.rank_address;
2486 select placex.place_id, osm_type, osm_id, name,
2487 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2488 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2489 admin_level, fromarea, isaddress,
2490 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,
2491 distance,country_code,postcode
2492 from place_addressline join placex on (address_place_id = placex.place_id)
2493 where place_addressline.place_id = for_place_id
2494 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2495 and address_place_id != for_place_id
2496 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2497 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2499 --RAISE WARNING '%',location;
2500 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2501 searchcountrycode := location.country_code;
2503 IF location.type in ('postcode', 'postal_code') THEN
2504 location.isaddress := FALSE;
2506 IF location.rank_address = 4 AND location.isaddress THEN
2509 IF location.rank_address < 4 AND NOT hadcountry THEN
2510 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2511 IF countryname IS NOT NULL THEN
2512 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2513 RETURN NEXT countrylocation;
2516 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2517 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2518 location.distance)::addressline;
2519 RETURN NEXT countrylocation;
2520 found := location.rank_address;
2524 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2525 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2526 IF countryname IS NOT NULL THEN
2527 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2528 RETURN NEXT location;
2532 IF searchcountrycode IS NOT NULL THEN
2533 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2534 RETURN NEXT location;
2537 IF searchhousename IS NOT NULL THEN
2538 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2539 RETURN NEXT location;
2542 IF searchhousenumber IS NOT NULL THEN
2543 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2544 RETURN NEXT location;
2547 IF searchpostcode IS NOT NULL THEN
2548 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2549 RETURN NEXT location;
2558 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2564 ELSEIF rank < 4 THEN
2566 ELSEIF rank < 8 THEN
2568 ELSEIF rank < 12 THEN
2570 ELSEIF rank < 16 THEN
2572 ELSEIF rank = 16 THEN
2574 ELSEIF rank = 17 THEN
2575 RETURN 'Town / Island';
2576 ELSEIF rank = 18 THEN
2577 RETURN 'Village / Hamlet';
2578 ELSEIF rank = 20 THEN
2580 ELSEIF rank = 21 THEN
2581 RETURN 'Postcode Area';
2582 ELSEIF rank = 22 THEN
2583 RETURN 'Croft / Farm / Locality / Islet';
2584 ELSEIF rank = 23 THEN
2585 RETURN 'Postcode Area';
2586 ELSEIF rank = 25 THEN
2587 RETURN 'Postcode Point';
2588 ELSEIF rank = 26 THEN
2589 RETURN 'Street / Major Landmark';
2590 ELSEIF rank = 27 THEN
2591 RETURN 'Minory Street / Path';
2592 ELSEIF rank = 28 THEN
2593 RETURN 'House / Building';
2595 RETURN 'Other: '||rank;
2602 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2608 ELSEIF rank < 2 THEN
2610 ELSEIF rank < 4 THEN
2612 ELSEIF rank = 5 THEN
2614 ELSEIF rank < 8 THEN
2616 ELSEIF rank < 12 THEN
2618 ELSEIF rank < 16 THEN
2620 ELSEIF rank = 16 THEN
2622 ELSEIF rank = 17 THEN
2623 RETURN 'Town / Village / Hamlet';
2624 ELSEIF rank = 20 THEN
2626 ELSEIF rank = 21 THEN
2627 RETURN 'Postcode Area';
2628 ELSEIF rank = 22 THEN
2629 RETURN 'Croft / Farm / Locality / Islet';
2630 ELSEIF rank = 23 THEN
2631 RETURN 'Postcode Area';
2632 ELSEIF rank = 25 THEN
2633 RETURN 'Postcode Point';
2634 ELSEIF rank = 26 THEN
2635 RETURN 'Street / Major Landmark';
2636 ELSEIF rank = 27 THEN
2637 RETURN 'Minory Street / Path';
2638 ELSEIF rank = 28 THEN
2639 RETURN 'House / Building';
2641 RETURN 'Other: '||rank;
2648 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2649 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2654 place_centroid GEOMETRY;
2655 out_partition INTEGER;
2656 out_parent_place_id BIGINT;
2658 address_street_word_id INTEGER;
2663 place_centroid := ST_Centroid(pointgeo);
2664 out_partition := get_partition(in_countrycode);
2665 out_parent_place_id := null;
2667 address_street_word_id := get_name_id(make_standard_name(in_street));
2668 IF address_street_word_id IS NOT NULL THEN
2669 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2670 out_parent_place_id := location.place_id;
2674 IF out_parent_place_id IS NULL THEN
2675 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2676 out_parent_place_id := location.place_id;
2680 out_postcode := in_postcode;
2681 IF out_postcode IS NULL THEN
2682 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2684 -- XXX look into postcode table
2687 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2688 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2689 newpoints := newpoints + 1;
2696 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2703 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2704 IF members[i+1] = member THEN
2705 result := result || members[i];
2714 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2720 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2721 IF members[i+1] = ANY(memberLabels) THEN
2722 RETURN NEXT members[i];
2731 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2732 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2734 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2735 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
2736 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2737 ), '') AS bytea), 'UTF8');
2739 LANGUAGE SQL IMMUTABLE STRICT;
2741 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2745 RETURN decode_url_part(p);
2747 WHEN others THEN return null;
2750 LANGUAGE plpgsql IMMUTABLE;
2752 DROP TYPE wikipedia_article_match CASCADE;
2753 create type wikipedia_article_match as (
2759 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2765 wiki_article_title TEXT;
2766 wiki_article_language TEXT;
2767 result wikipedia_article_match;
2769 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'];
2771 WHILE langs[i] IS NOT NULL LOOP
2772 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2773 IF wiki_article is not null THEN
2774 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2775 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2776 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2777 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2778 wiki_article := replace(wiki_article,' ','_');
2779 IF strpos(wiki_article, ':') IN (3,4) THEN
2780 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2781 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2783 wiki_article_title := trim(wiki_article);
2784 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;
2787 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2788 from wikipedia_article
2789 where language = wiki_article_language and
2790 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2792 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2793 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2794 where wikipedia_redirect.language = wiki_article_language and
2795 (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'\\',''))
2796 order by importance desc limit 1 INTO result;
2798 IF result.language is not null THEN
2809 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2810 RETURNS SETOF GEOMETRY
2824 remainingdepth INTEGER;
2829 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2831 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2832 RETURN NEXT geometry;
2836 remainingdepth := maxdepth - 1;
2837 area := ST_AREA(geometry);
2838 IF remainingdepth < 1 OR area < maxarea THEN
2839 RETURN NEXT geometry;
2843 xmin := st_xmin(geometry);
2844 xmax := st_xmax(geometry);
2845 ymin := st_ymin(geometry);
2846 ymax := st_ymax(geometry);
2847 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2849 -- if the geometry completely covers the box don't bother to slice any more
2850 IF ST_AREA(secbox) = area THEN
2851 RETURN NEXT geometry;
2855 xmid := (xmin+xmax)/2;
2856 ymid := (ymin+ymax)/2;
2859 FOR seg IN 1..4 LOOP
2862 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2865 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2868 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2871 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2874 IF st_intersects(geometry, secbox) THEN
2875 secgeo := st_intersection(geometry, secbox);
2876 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2877 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2878 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2880 RETURN NEXT geo.geom;
2892 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2893 RETURNS SETOF GEOMETRY
2898 -- 10000000000 is ~~ 1x1 degree
2899 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2900 RETURN NEXT geo.geom;
2908 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2912 osmtype character(1);
2916 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2917 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2918 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2919 -- force delete from place/placex by making it a very small geometry
2920 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;
2921 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2928 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2936 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2937 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2938 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2939 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2940 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2941 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2942 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'));
2943 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2944 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'));
2950 ELSEIF rank < 18 THEN
2952 ELSEIF rank < 20 THEN
2954 ELSEIF rank = 21 THEN
2956 ELSEIF rank < 24 THEN
2958 ELSEIF rank < 26 THEN
2959 diameter := 0.002; -- 100 to 200 meters
2960 ELSEIF rank < 28 THEN
2961 diameter := 0.001; -- 50 to 100 meters
2963 IF diameter > 0 THEN
2965 -- roads may cause reparenting for >27 rank places
2966 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2967 ELSEIF rank >= 16 THEN
2968 -- up to rank 16, street-less addresses may need reparenting
2969 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');
2971 -- for all other places the search terms may change as well
2972 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);