1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
91 return_word_id INTEGER;
93 lookup_token := ' '||trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
145 nospace_lookup_token TEXT;
146 return_word_id INTEGER;
148 lookup_token := ' '||trim(lookup_word);
149 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
150 IF return_word_id IS NULL THEN
151 return_word_id := nextval('seq_word');
152 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
153 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
154 -- IF ' '||nospace_lookup_token != lookup_token THEN
155 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
168 RETURN getorcreate_name_id(lookup_word, '');
173 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
178 return_word_id INTEGER;
180 lookup_token := trim(lookup_word);
181 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
182 RETURN return_word_id;
185 LANGUAGE plpgsql IMMUTABLE;
187 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
192 return_word_id INTEGER;
194 lookup_token := ' '||trim(lookup_word);
195 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
196 RETURN return_word_id;
199 LANGUAGE plpgsql IMMUTABLE;
201 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
206 return_word_ids INTEGER[];
208 lookup_token := ' '||trim(lookup_word);
209 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
210 RETURN return_word_ids;
213 LANGUAGE plpgsql IMMUTABLE;
215 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
222 IF array_upper(a, 1) IS NULL THEN
225 IF array_upper(b, 1) IS NULL THEN
229 FOR i IN 1..array_upper(b, 1) LOOP
230 IF NOT (ARRAY[b[i]] <@ r) THEN
237 LANGUAGE plpgsql IMMUTABLE;
240 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
241 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
249 IF country_code = 'gb' THEN
250 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
253 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
256 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
261 ELSEIF country_code = 'sg' THEN
262 IF postcode ~ '^([0-9]{6})$' THEN
267 ELSEIF country_code = 'de' THEN
268 IF postcode ~ '^([0-9]{5})$' THEN
274 -- Guess at the postcode format and coverage (!)
275 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
279 -- Does it look splitable into and area and local code?
280 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
282 IF part IS NOT NULL THEN
285 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
294 LANGUAGE plpgsql IMMUTABLE;
298 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
307 FOR item IN SELECT (each(src)).* LOOP
309 s := make_standard_name(item.value);
310 w := getorcreate_country(s, lookup_country_code);
312 words := regexp_split_to_array(item.value, E'[,;()]');
313 IF array_upper(words, 1) != 1 THEN
314 FOR j IN 1..array_upper(words, 1) LOOP
315 s := make_standard_name(words[j]);
317 w := getorcreate_country(s, lookup_country_code);
326 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
336 result := '{}'::INTEGER[];
338 FOR item IN SELECT (each(src)).* LOOP
340 s := make_standard_name(item.value);
342 w := getorcreate_name_id(s, item.value);
344 IF not(ARRAY[w] <@ result) THEN
345 result := result || w;
348 w := getorcreate_word_id(s);
350 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
351 result := result || w;
354 words := string_to_array(s, ' ');
355 IF array_upper(words, 1) IS NOT NULL THEN
356 FOR j IN 1..array_upper(words, 1) LOOP
357 IF (words[j] != '') THEN
358 w = getorcreate_word_id(words[j]);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
366 words := regexp_split_to_array(item.value, E'[,;()]');
367 IF array_upper(words, 1) != 1 THEN
368 FOR j IN 1..array_upper(words, 1) LOOP
369 s := make_standard_name(words[j]);
371 w := getorcreate_word_id(s);
372 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
373 result := result || w;
379 s := regexp_replace(item.value, '市$', '');
380 IF s != item.value THEN
381 s := make_standard_name(s);
383 w := getorcreate_name_id(s, item.value);
384 IF NOT (ARRAY[w] <@ result) THEN
385 result := result || w;
395 LANGUAGE plpgsql IMMUTABLE;
397 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
407 result := '{}'::INTEGER[];
409 s := make_standard_name(src);
410 w := getorcreate_name_id(s, src);
412 IF NOT (ARRAY[w] <@ result) THEN
413 result := result || w;
416 w := getorcreate_word_id(s);
418 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
419 result := result || w;
422 words := string_to_array(s, ' ');
423 IF array_upper(words, 1) IS NOT NULL THEN
424 FOR j IN 1..array_upper(words, 1) LOOP
425 IF (words[j] != '') THEN
426 w = getorcreate_word_id(words[j]);
427 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
428 result := result || w;
434 words := regexp_split_to_array(src, E'[,;()]');
435 IF array_upper(words, 1) != 1 THEN
436 FOR j IN 1..array_upper(words, 1) LOOP
437 s := make_standard_name(words[j]);
439 w := getorcreate_word_id(s);
440 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
441 result := result || w;
447 s := regexp_replace(src, '市$', '');
449 s := make_standard_name(s);
451 w := getorcreate_name_id(s, src);
452 IF NOT (ARRAY[w] <@ result) THEN
453 result := result || w;
461 LANGUAGE plpgsql IMMUTABLE;
463 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
466 place_centre GEOMETRY;
469 place_centre := ST_PointOnSurface(place);
471 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
473 -- Try for a OSM polygon
474 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
476 RETURN nearcountry.country_code;
479 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
481 -- Try for OSM fallback data
482 -- The order is to deal with places like HongKong that are 'states' within another polygon
483 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
485 RETURN nearcountry.country_code;
488 -- RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
490 -- Natural earth data
491 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
493 RETURN nearcountry.country_code;
496 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
499 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
501 RETURN nearcountry.country_code;
504 -- RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
506 -- Natural earth data
507 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
509 RETURN nearcountry.country_code;
515 LANGUAGE plpgsql IMMUTABLE;
517 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
522 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
524 RETURN lower(nearcountry.country_default_language_code);
529 LANGUAGE plpgsql IMMUTABLE;
531 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
536 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
538 RETURN lower(nearcountry.country_default_language_codes);
543 LANGUAGE plpgsql IMMUTABLE;
545 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
550 FOR nearcountry IN select partition from country_name where country_code = in_country_code
552 RETURN nearcountry.partition;
557 LANGUAGE plpgsql IMMUTABLE;
559 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
563 DELETE FROM location_area where place_id = OLD_place_id;
564 -- TODO:location_area
570 CREATE OR REPLACE FUNCTION add_location(
572 country_code varchar(2),
576 rank_address INTEGER,
592 IF rank_search > 25 THEN
593 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
596 x := deleteLocationArea(partition, place_id, rank_search);
598 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
599 IF in_postcode IS NULL OR in_postcode similar to '%(,|;)%' THEN
602 postcode := in_postcode;
605 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
606 centroid := ST_Centroid(geometry);
608 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
609 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
615 IF rank_address = 0 THEN
617 ELSEIF rank_search <= 14 THEN
619 ELSEIF rank_search <= 15 THEN
621 ELSEIF rank_search <= 16 THEN
623 ELSEIF rank_search <= 17 THEN
625 ELSEIF rank_search <= 21 THEN
627 ELSEIF rank_search = 25 THEN
631 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
633 secgeo := ST_Buffer(geometry, diameter);
634 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
644 -- find the parent road of the cut road parts
645 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
646 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
651 parent_place_id BIGINT;
652 address_street_word_ids INTEGER[];
658 addr_street = street;
661 IF addr_street is null and addr_place is null THEN
662 select nodes from planet_osm_ways where id = wayid INTO waynodes;
663 FOR location IN SELECT placex.address from placex
664 where osm_type = 'N' and osm_id = ANY(waynodes)
665 and placex.address is not null
666 and (placex.address ? 'street' or placex.address ? 'place')
667 and indexed_status < 100
669 addr_street = location.address->'street';
670 addr_place = location.address->'place';
674 IF addr_street IS NOT NULL THEN
675 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
676 IF address_street_word_ids IS NOT NULL THEN
677 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
678 parent_place_id := location.place_id;
683 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
684 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
685 IF address_street_word_ids IS NOT NULL THEN
686 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
687 parent_place_id := location.place_id;
692 IF parent_place_id is null THEN
693 FOR location IN SELECT place_id FROM placex
694 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
695 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
696 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
697 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
699 parent_place_id := location.place_id;
703 IF parent_place_id is null THEN
707 RETURN parent_place_id;
713 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
716 NEW.place_id := nextval('seq_place');
717 NEW.indexed_date := now();
719 IF NEW.indexed_status IS NULL THEN
720 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
721 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
722 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
726 NEW.indexed_status := 1; --STATUS_NEW
727 NEW.country_code := lower(get_country_code(NEW.linegeo));
729 NEW.partition := get_partition(NEW.country_code);
730 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
739 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
745 country_code VARCHAR(2);
746 default_language VARCHAR(10);
751 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
753 NEW.place_id := nextval('seq_place');
754 NEW.indexed_status := 1; --STATUS_NEW
756 NEW.country_code := lower(get_country_code(NEW.geometry));
758 NEW.partition := get_partition(NEW.country_code);
759 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
761 -- copy 'name' to or from the default language (if there is a default language)
762 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
763 default_language := get_country_language_code(NEW.country_code);
764 IF default_language IS NOT NULL THEN
765 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
766 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
767 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
768 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
773 IF NEW.osm_type = 'X' THEN
774 -- E'X'ternal records should already be in the right format so do nothing
776 NEW.rank_search := 30;
777 NEW.rank_address := NEW.rank_search;
779 -- By doing in postgres we have the country available to us - currently only used for postcode
780 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
782 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
783 -- most likely just a part of a multipolygon postcode boundary, throw it away
787 NEW.postcode := NEW.address->'postcode';
788 NEW.name := hstore('ref', NEW.postcode);
790 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
791 INTO NEW.rank_search, NEW.rank_address;
793 ELSEIF NEW.class = 'place' THEN
794 IF NEW.type in ('continent') THEN
795 NEW.rank_search := 2;
796 NEW.rank_address := NEW.rank_search;
797 NEW.country_code := NULL;
798 ELSEIF NEW.type in ('sea') THEN
799 NEW.rank_search := 2;
800 NEW.rank_address := 0;
801 NEW.country_code := NULL;
802 ELSEIF NEW.type in ('country') THEN
803 NEW.rank_search := 4;
804 NEW.rank_address := NEW.rank_search;
805 ELSEIF NEW.type in ('state') THEN
806 NEW.rank_search := 8;
807 NEW.rank_address := NEW.rank_search;
808 ELSEIF NEW.type in ('region') THEN
809 NEW.rank_search := 18; -- dropped from previous value of 10
810 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
811 ELSEIF NEW.type in ('county') THEN
812 NEW.rank_search := 12;
813 NEW.rank_address := NEW.rank_search;
814 ELSEIF NEW.type in ('city') THEN
815 NEW.rank_search := 16;
816 NEW.rank_address := NEW.rank_search;
817 ELSEIF NEW.type in ('island') THEN
818 NEW.rank_search := 17;
819 NEW.rank_address := 0;
820 ELSEIF NEW.type in ('town') THEN
821 NEW.rank_search := 18;
822 NEW.rank_address := 16;
823 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
824 NEW.rank_search := 19;
825 NEW.rank_address := 16;
826 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
827 NEW.rank_search := 20;
828 NEW.rank_address := NEW.rank_search;
829 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
830 NEW.rank_search := 20;
831 NEW.rank_address := 0;
832 -- Irish townlands, tagged as place=locality and locality=townland
833 IF (NEW.extratags -> 'locality') = 'townland' THEN
834 NEW.rank_address := 20;
836 ELSEIF NEW.type in ('neighbourhood') THEN
837 NEW.rank_search := 22;
838 NEW.rank_address := 22;
839 ELSEIF NEW.type in ('house','building') THEN
840 NEW.rank_search := 30;
841 NEW.rank_address := NEW.rank_search;
842 ELSEIF NEW.type in ('houses') THEN
843 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
844 NEW.rank_search := 28;
845 NEW.rank_address := 0;
848 ELSEIF NEW.class = 'boundary' THEN
849 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
850 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
853 NEW.rank_search := NEW.admin_level * 2;
854 IF NEW.type = 'administrative' THEN
855 NEW.rank_address := NEW.rank_search;
857 NEW.rank_address := 0;
859 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
860 NEW.rank_search := 22;
861 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
862 NEW.rank_address := NEW.rank_search;
864 NEW.rank_address := 0;
866 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
867 NEW.rank_search := 18;
868 NEW.rank_address := 0;
869 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
870 NEW.rank_search := 4;
871 NEW.rank_address := NEW.rank_search;
872 -- any feature more than 5 square miles is probably worth indexing
873 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
874 NEW.rank_search := 22;
875 NEW.rank_address := 0;
876 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
878 ELSEIF NEW.class = 'waterway' THEN
879 IF NEW.osm_type = 'R' THEN
880 NEW.rank_search := 16;
882 NEW.rank_search := 17;
884 NEW.rank_address := 0;
885 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
886 NEW.rank_search := 27;
887 NEW.rank_address := NEW.rank_search;
888 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
889 NEW.rank_search := 26;
890 NEW.rank_address := NEW.rank_search;
891 ELSEIF NEW.class = 'mountain_pass' THEN
892 NEW.rank_search := 20;
893 NEW.rank_address := 0;
898 IF NEW.rank_search > 30 THEN
899 NEW.rank_search := 30;
902 IF NEW.rank_address > 30 THEN
903 NEW.rank_address := 30;
906 IF (NEW.extratags -> 'capital') = 'yes' THEN
907 NEW.rank_search := NEW.rank_search - 1;
910 -- a country code make no sense below rank 4 (country)
911 IF NEW.rank_search < 4 THEN
912 NEW.country_code := NULL;
915 -- Block import below rank 22
916 -- IF NEW.rank_search > 22 THEN
920 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
922 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
924 IF NEW.rank_address > 0 THEN
925 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
926 -- Performance: We just can't handle re-indexing for country level changes
927 IF st_area(NEW.geometry) < 1 THEN
928 -- mark items within the geometry for re-indexing
929 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
931 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
932 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
933 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'));
934 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
935 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'));
938 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
940 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
941 IF NEW.type='postcode' THEN
943 ELSEIF NEW.rank_search < 16 THEN
945 ELSEIF NEW.rank_search < 18 THEN
947 ELSEIF NEW.rank_search < 20 THEN
949 ELSEIF NEW.rank_search = 21 THEN
951 ELSEIF NEW.rank_search < 24 THEN
953 ELSEIF NEW.rank_search < 26 THEN
954 diameter := 0.002; -- 100 to 200 meters
955 ELSEIF NEW.rank_search < 28 THEN
956 diameter := 0.001; -- 50 to 100 meters
959 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
960 IF NEW.rank_search >= 26 THEN
961 -- roads may cause reparenting for >27 rank places
962 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
963 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
964 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
965 ELSEIF NEW.rank_search >= 16 THEN
966 -- up to rank 16, street-less addresses may need reparenting
967 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');
969 -- for all other places the search terms may change as well
970 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);
977 -- add to tables for special search
978 -- Note: won't work on initial import because the classtype tables
979 -- do not yet exist. It won't hurt either.
980 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
981 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
983 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
984 USING NEW.place_id, ST_Centroid(NEW.geometry);
993 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
997 place_centroid GEOMETRY;
1001 startnumber INTEGER;
1006 sectiongeo GEOMETRY;
1011 IF OLD.indexed_status = 100 THEN
1012 delete from location_property_osmline where place_id = OLD.place_id;
1016 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1020 NEW.interpolationtype = NEW.address->'interpolation';
1022 place_centroid := ST_PointOnSurface(NEW.linegeo);
1023 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1024 NEW.address->'place',
1025 NEW.partition, place_centroid, NEW.linegeo);
1028 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1029 NEW.postcode = NEW.address->'postcode';
1032 -- if the line was newly inserted, split the line as necessary
1033 IF OLD.indexed_status = 1 THEN
1034 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1036 IF array_upper(waynodes, 1) IS NULL THEN
1040 linegeo := NEW.linegeo;
1041 startnumber := NULL;
1042 postcode := NEW.postcode;
1044 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1046 select osm_id, address, geometry
1047 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1048 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1049 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1050 IF nextnode.osm_id IS NOT NULL THEN
1051 --RAISE NOTICE 'place_id is not null';
1052 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1053 -- Make sure that the point is actually on the line. That might
1054 -- be a bit paranoid but ensures that the algorithm still works
1055 -- should osm2pgsql attempt to repair geometries.
1056 splitline := split_line_on_node(linegeo, nextnode.geometry);
1057 sectiongeo := ST_GeometryN(splitline, 1);
1058 linegeo := ST_GeometryN(splitline, 2);
1060 sectiongeo = linegeo;
1062 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1064 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1065 AND startnumber != endnumber
1066 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1068 IF (startnumber > endnumber) THEN
1069 housenum := endnumber;
1070 endnumber := startnumber;
1071 startnumber := housenum;
1072 sectiongeo := ST_Reverse(sectiongeo);
1075 seg_postcode := coalesce(postcode,
1076 prevnode.address->'postcode',
1077 nextnode.address->'postcode');
1079 IF NEW.startnumber IS NULL THEN
1080 NEW.startnumber := startnumber;
1081 NEW.endnumber := endnumber;
1082 NEW.linegeo := sectiongeo;
1083 NEW.postcode := seg_postcode;
1085 insert into location_property_osmline
1086 (linegeo, partition, osm_id, parent_place_id,
1087 startnumber, endnumber, interpolationtype,
1088 address, postcode, country_code,
1089 geometry_sector, indexed_status)
1090 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1091 startnumber, endnumber, NEW.interpolationtype,
1092 NEW.address, seg_postcode,
1093 NEW.country_code, NEW.geometry_sector, 0);
1097 -- early break if we are out of line string,
1098 -- might happen when a line string loops back on itself
1099 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1103 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1104 prevnode := nextnode;
1109 -- marking descendants for reparenting is not needed, because there are
1110 -- actually no descendants for interpolation lines
1116 -- Trigger for updates of location_postcode
1118 -- Computes the parent object the postcode most likely refers to.
1119 -- This will be the place that determines the address displayed when
1120 -- searching for this postcode.
1121 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1128 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1132 NEW.indexed_date = now();
1134 partition := get_partition(NEW.country_code);
1136 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1137 INTO NEW.rank_search, NEW.rank_address;
1139 NEW.parent_place_id = 0;
1142 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1143 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1145 NEW.parent_place_id = location.place_id;
1153 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1158 place_centroid GEOMETRY;
1160 search_maxdistance FLOAT[];
1161 search_mindistance FLOAT[];
1162 address_havelevel BOOLEAN[];
1169 relation_members TEXT[];
1171 linkedplacex RECORD;
1172 search_diameter FLOAT;
1173 search_prevdiameter FLOAT;
1174 search_maxrank INTEGER;
1175 address_maxrank INTEGER;
1176 address_street_word_id INTEGER;
1177 address_street_word_ids INTEGER[];
1178 parent_place_id_rank BIGINT;
1186 location_rank_search INTEGER;
1187 location_distance FLOAT;
1188 location_parent GEOMETRY;
1189 location_isaddress BOOLEAN;
1190 location_keywords INTEGER[];
1192 default_language TEXT;
1193 name_vector INTEGER[];
1194 nameaddress_vector INTEGER[];
1196 linked_node_id BIGINT;
1197 linked_importance FLOAT;
1198 linked_wikipedia TEXT;
1203 IF OLD.indexed_status = 100 THEN
1204 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1205 delete from placex where place_id = OLD.place_id;
1209 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1213 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1215 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1216 -- Silently do nothing
1220 NEW.indexed_date = now();
1222 result := deleteSearchName(NEW.partition, NEW.place_id);
1223 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1224 result := deleteRoad(NEW.partition, NEW.place_id);
1225 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1226 UPDATE placex set linked_place_id = null, indexed_status = 2
1227 where linked_place_id = NEW.place_id;
1228 -- update not necessary for osmline, cause linked_place_id does not exist
1230 IF NEW.linked_place_id is not null THEN
1231 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1235 --DEBUG: RAISE WARNING 'Copy over address tags';
1236 IF NEW.address is not NULL THEN
1237 IF NEW.address ? 'conscriptionnumber' THEN
1238 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1239 IF NEW.address ? 'streetnumber' THEN
1240 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1241 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1243 NEW.housenumber := NEW.address->'conscriptionnumber';
1245 ELSEIF NEW.address ? 'streetnumber' THEN
1246 NEW.housenumber := NEW.address->'streetnumber';
1247 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1248 ELSEIF NEW.address ? 'housenumber' THEN
1249 NEW.housenumber := NEW.address->'housenumber';
1250 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1253 addr_street = NEW.address->'street';
1254 addr_place = NEW.address->'place';
1256 NEW.postcode = NEW.address->'postcode';
1259 -- Speed up searches - just use the centroid of the feature
1260 -- cheaper but less acurate
1261 place_centroid := ST_PointOnSurface(NEW.geometry);
1262 NEW.centroid := null;
1263 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1265 -- recalculate country and partition
1266 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1267 -- for countries, believe the mapped country code,
1268 -- so that we remain in the right partition if the boundaries
1270 NEW.country_code := lower(NEW.address->'country');
1271 NEW.partition := get_partition(lower(NEW.country_code));
1272 IF NEW.partition = 0 THEN
1273 NEW.country_code := lower(get_country_code(place_centroid));
1274 NEW.partition := get_partition(NEW.country_code);
1277 IF NEW.rank_search >= 4 THEN
1278 NEW.country_code := lower(get_country_code(place_centroid));
1280 NEW.country_code := NULL;
1282 NEW.partition := get_partition(NEW.country_code);
1284 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1286 -- waterway ways are linked when they are part of a relation and have the same class/type
1287 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1288 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1290 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1291 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1292 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1293 FOR linked_node_id IN SELECT place_id FROM placex
1294 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1295 and class = NEW.class and type = NEW.type
1296 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1298 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1303 --DEBUG: RAISE WARNING 'Waterway processed';
1306 -- Adding ourselves to the list simplifies address calculations later
1307 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1308 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1310 -- What level are we searching from
1311 search_maxrank := NEW.rank_search;
1313 -- Thought this wasn't needed but when we add new languages to the country_name table
1314 -- we need to update the existing names
1315 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1316 default_language := get_country_language_code(NEW.country_code);
1317 IF default_language IS NOT NULL THEN
1318 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1319 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1320 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1321 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1325 --DEBUG: RAISE WARNING 'Local names updated';
1327 -- Initialise the name vector using our name
1328 name_vector := make_keywords(NEW.name);
1329 nameaddress_vector := '{}'::int[];
1332 address_havelevel[i] := false;
1335 NEW.importance := null;
1336 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1337 IF NEW.importance IS NULL THEN
1338 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;
1341 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1343 -- ---------------------------------------------------------------------------
1344 -- For low level elements we inherit from our parent road
1345 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1347 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1349 -- We won't get a better centroid, besides these places are too small to care
1350 NEW.centroid := place_centroid;
1352 NEW.parent_place_id := null;
1354 -- if we have a POI and there is no address information,
1355 -- see if we can get it from a surrounding building
1356 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1357 AND NEW.housenumber IS NULL THEN
1358 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1359 and address is not null
1360 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1361 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1364 NEW.housenumber := location.address->'housenumber';
1365 addr_street := location.address->'street';
1366 addr_place := location.address->'place';
1367 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1371 -- We have to find our parent road.
1372 -- Copy data from linked items (points on ways, addr:street links, relations)
1374 -- Is this object part of a relation?
1375 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1377 -- At the moment we only process one type of relation - associatedStreet
1378 IF relation.tags @> ARRAY['associatedStreet'] THEN
1379 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1380 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1381 --RAISE WARNING 'node in relation %',relation;
1382 SELECT place_id from placex where osm_type = 'W'
1383 and osm_id = substring(relation.members[i],2,200)::bigint
1384 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1389 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1391 -- Note that addr:street links can only be indexed once the street itself is indexed
1392 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1393 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1394 IF address_street_word_ids IS NOT NULL THEN
1395 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1396 NEW.parent_place_id := location.place_id;
1400 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1402 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1403 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1404 IF address_street_word_ids IS NOT NULL THEN
1405 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1406 NEW.parent_place_id := location.place_id;
1410 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1412 -- Is this node part of an interpolation?
1413 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1415 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1416 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1419 NEW.parent_place_id := location.parent_place_id;
1422 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1424 -- Is this node part of a way?
1425 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1427 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
1428 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)
1430 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1432 -- Way IS a road then we are on it - that must be our road
1433 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1434 --RAISE WARNING 'node in way that is a street %',location;
1435 NEW.parent_place_id := location.place_id;
1437 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1439 -- If the way mentions a street or place address, try that for parenting.
1440 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1441 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1442 IF address_street_word_ids IS NOT NULL THEN
1443 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1444 NEW.parent_place_id := linkedplacex.place_id;
1448 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1450 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1451 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1452 IF address_street_word_ids IS NOT NULL THEN
1453 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1454 NEW.parent_place_id := linkedplacex.place_id;
1458 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1460 -- Is the WAY part of a relation
1461 IF NEW.parent_place_id IS NULL THEN
1462 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1464 -- At the moment we only process one type of relation - associatedStreet
1465 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1466 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1467 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1468 --RAISE WARNING 'node in way that is in a relation %',relation;
1469 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1470 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1476 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1482 -- Still nothing, just use the nearest road
1483 IF NEW.parent_place_id IS NULL THEN
1484 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1485 NEW.parent_place_id := location.place_id;
1488 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1491 -- If we didn't find any road fallback to standard method
1492 IF NEW.parent_place_id IS NOT NULL THEN
1494 -- Get the details of the parent road
1495 select * from search_name where place_id = NEW.parent_place_id INTO location;
1496 NEW.country_code := location.country_code;
1497 --DEBUG: RAISE WARNING 'Got parent details from search name';
1499 -- Merge the postcode into the parent's address if necessary
1500 IF NEW.postcode IS NOT NULL THEN
1501 --DEBUG: RAISE WARNING 'Merging postcode into parent';
1502 isin_tokens := '{}'::int[];
1503 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1504 IF address_street_word_id is not null
1505 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1506 isin_tokens := isin_tokens || address_street_word_id;
1508 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1509 IF address_street_word_id is not null
1510 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1511 isin_tokens := isin_tokens || address_street_word_id;
1513 IF isin_tokens != '{}'::int[] THEN
1515 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1516 WHERE place_id = NEW.parent_place_id;
1520 -- If there is no name it isn't searchable, don't bother to create a search record
1521 IF NEW.name is NULL THEN
1522 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1526 -- Merge address from parent
1527 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1528 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1530 -- Performance, it would be more acurate to do all the rest of the import
1531 -- process but it takes too long
1532 -- Just be happy with inheriting from parent road only
1534 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1535 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1536 --DEBUG: RAISE WARNING 'Place added to location table';
1539 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);
1540 --DEBUG: RAISE WARNING 'Place added to search table';
1547 -- ---------------------------------------------------------------------------
1549 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1551 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1553 -- see if we have any special relation members
1554 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1555 --DEBUG: RAISE WARNING 'Got relation members';
1557 IF relation_members IS NOT NULL THEN
1558 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1559 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1561 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1562 and osm_id = substring(relMember.member,2,10000)::bigint
1563 and class = 'place' order by rank_search desc limit 1 LOOP
1565 -- If we don't already have one use this as the centre point of the geometry
1566 IF NEW.centroid IS NULL THEN
1567 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1570 -- merge in the label name, re-init word vector
1571 IF NOT linkedPlacex.name IS NULL THEN
1572 NEW.name := linkedPlacex.name || NEW.name;
1573 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1576 -- merge in extra tags
1577 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1579 -- mark the linked place (excludes from search results)
1580 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1582 -- keep a note of the node id in case we need it for wikipedia in a bit
1583 linked_node_id := linkedPlacex.osm_id;
1584 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1585 --DEBUG: RAISE WARNING 'Linked label member';
1590 IF NEW.centroid IS NULL THEN
1592 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1593 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1595 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1596 and osm_id = substring(relMember.member,2,10000)::bigint
1597 and class = 'place' order by rank_search desc limit 1 LOOP
1599 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1600 -- But that can be fixed by explicitly setting the label in the data
1601 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1602 AND NEW.rank_address = linkedPlacex.rank_address THEN
1604 -- If we don't already have one use this as the centre point of the geometry
1605 IF NEW.centroid IS NULL THEN
1606 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1609 -- merge in the name, re-init word vector
1610 IF NOT linkedPlacex.name IS NULL THEN
1611 NEW.name := linkedPlacex.name || NEW.name;
1612 name_vector := make_keywords(NEW.name);
1615 -- merge in extra tags
1616 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1618 -- mark the linked place (excludes from search results)
1619 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1621 -- keep a note of the node id in case we need it for wikipedia in a bit
1622 linked_node_id := linkedPlacex.osm_id;
1623 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1624 --DEBUG: RAISE WARNING 'Linked admin_center';
1636 -- Name searches can be done for ways as well as relations
1637 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1639 -- not found one yet? how about doing a name search
1640 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1642 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1643 FOR linkedPlacex IN select placex.* from placex WHERE
1644 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1645 AND placex.rank_address = NEW.rank_address
1646 AND placex.place_id != NEW.place_id
1647 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1648 AND st_covers(NEW.geometry, placex.geometry)
1650 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1651 -- If we don't already have one use this as the centre point of the geometry
1652 IF NEW.centroid IS NULL THEN
1653 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1656 -- merge in the name, re-init word vector
1657 NEW.name := linkedPlacex.name || NEW.name;
1658 name_vector := make_keywords(NEW.name);
1660 -- merge in extra tags
1661 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1663 -- mark the linked place (excludes from search results)
1664 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1666 -- keep a note of the node id in case we need it for wikipedia in a bit
1667 linked_node_id := linkedPlacex.osm_id;
1668 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1669 --DEBUG: RAISE WARNING 'Linked named place';
1673 IF NEW.centroid IS NOT NULL THEN
1674 place_centroid := NEW.centroid;
1675 -- Place might have had only a name tag before but has now received translations
1676 -- from the linked place. Make sure a name tag for the default language exists in
1678 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1679 default_language := get_country_language_code(NEW.country_code);
1680 IF default_language IS NOT NULL THEN
1681 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1682 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1683 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1684 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1688 --DEBUG: RAISE WARNING 'Names updated from linked places';
1691 -- Use the maximum importance if a one could be computed from the linked object.
1692 IF linked_importance is not null AND
1693 (NEW.importance is null or NEW.importance < linked_importance) THEN
1694 NEW.importance = linked_importance;
1697 -- Still null? how about looking it up by the node id
1698 IF NEW.importance IS NULL THEN
1699 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1700 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;
1705 -- make sure all names are in the word table
1706 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1707 perform create_country(NEW.name, lower(NEW.country_code));
1708 --DEBUG: RAISE WARNING 'Country names updated';
1711 NEW.parent_place_id = 0;
1712 parent_place_id_rank = 0;
1715 -- convert isin to array of tokenids
1716 --DEBUG: RAISE WARNING 'Starting address search';
1717 isin_tokens := '{}'::int[];
1718 IF NEW.address IS NOT NULL THEN
1719 isin := avals(NEW.address);
1720 IF array_upper(isin, 1) IS NOT NULL THEN
1721 FOR i IN 1..array_upper(isin, 1) LOOP
1722 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1723 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1724 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1725 isin_tokens := isin_tokens || address_street_word_id;
1728 -- merge word into address vector
1729 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1730 IF address_street_word_id IS NOT NULL THEN
1731 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1736 --DEBUG: RAISE WARNING '"address:* tokens collected';
1737 IF NEW.postcode IS NOT NULL THEN
1738 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1739 IF array_upper(isin, 1) IS NOT NULL THEN
1740 FOR i IN 1..array_upper(isin, 1) LOOP
1741 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1742 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1743 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1744 isin_tokens := isin_tokens || address_street_word_id;
1747 -- merge into address vector
1748 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1749 IF address_street_word_id IS NOT NULL THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1755 --DEBUG: RAISE WARNING 'postcode tokens collected';
1757 -- %NOTIGERDATA% IF 0 THEN
1758 -- for the USA we have an additional address table. Merge in zip codes from there too
1759 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1760 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1761 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1762 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1763 isin_tokens := isin_tokens || address_street_word_id;
1765 -- also merge in the single word version
1766 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1767 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1770 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1771 -- %NOTIGERDATA% END IF;
1773 -- RAISE WARNING 'ISIN: %', isin_tokens;
1775 -- Process area matches
1776 location_rank_search := 0;
1777 location_distance := 0;
1778 location_parent := NULL;
1779 -- added ourself as address already
1780 address_havelevel[NEW.rank_address] := true;
1781 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1783 SELECT * from getNearFeatures(NEW.partition,
1784 CASE WHEN NEW.rank_search >= 26
1785 AND NEW.rank_search < 30
1787 ELSE place_centroid END,
1788 search_maxrank, isin_tokens)
1790 IF location.rank_address != location_rank_search THEN
1791 location_rank_search := location.rank_address;
1792 IF location.isguess THEN
1793 location_distance := location.distance * 1.5;
1795 IF location.rank_address <= 12 THEN
1796 -- for county and above, if we have an area consider that exact
1797 -- (It would be nice to relax the constraint for places close to
1798 -- the boundary but we'd need the exact geometry for that. Too
1800 location_distance = 0;
1802 -- Below county level remain slightly fuzzy.
1803 location_distance := location.distance * 0.5;
1807 CONTINUE WHEN location.keywords <@ location_keywords;
1810 IF location.distance < location_distance OR NOT location.isguess THEN
1811 location_keywords := location.keywords;
1813 location_isaddress := NOT address_havelevel[location.rank_address];
1814 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1815 location_isaddress := ST_Contains(location_parent,location.centroid);
1818 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1819 -- Add it to the list of search terms
1820 IF location.rank_search > 4 THEN
1821 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1823 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1824 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1826 IF location_isaddress THEN
1828 address_havelevel[location.rank_address] := true;
1829 IF NOT location.isguess THEN
1830 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1833 IF location.rank_address > parent_place_id_rank THEN
1834 NEW.parent_place_id = location.place_id;
1835 parent_place_id_rank = location.rank_address;
1840 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1845 --DEBUG: RAISE WARNING 'address computed';
1847 -- try using the isin value to find parent places
1848 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1849 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1850 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1851 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1853 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1855 --RAISE WARNING ' ISIN: %',location;
1857 IF location.rank_search > 4 THEN
1858 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1859 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1860 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1861 address_havelevel[location.rank_address] := true;
1863 IF location.rank_address > parent_place_id_rank THEN
1864 NEW.parent_place_id = location.place_id;
1865 parent_place_id_rank = location.rank_address;
1874 --DEBUG: RAISE WARNING 'isin tokens processed';
1876 -- for long ways we should add search terms for the entire length
1877 IF st_length(NEW.geometry) > 0.05 THEN
1879 location_rank_search := 0;
1880 location_distance := 0;
1882 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1884 IF location.rank_address != location_rank_search THEN
1885 location_rank_search := location.rank_address;
1886 location_distance := location.distance * 1.5;
1889 IF location.rank_search > 4 AND location.distance < location_distance THEN
1891 -- Add it to the list of search terms
1892 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1893 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1894 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1901 --DEBUG: RAISE WARNING 'search terms for long ways added';
1903 -- if we have a name add this to the name search table
1904 IF NEW.name IS NOT NULL THEN
1906 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1907 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.address->'postcode', NEW.geometry);
1908 --DEBUG: RAISE WARNING 'added to location (full)';
1911 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1912 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1913 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1916 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);
1917 --DEBUG: RAISE WARNING 'added to serach name (full)';
1921 -- If we've not managed to pick up a better one - default centroid
1922 IF NEW.centroid IS NULL THEN
1923 NEW.centroid := place_centroid;
1926 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1933 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1939 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1941 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1942 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1943 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1944 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1946 IF OLD.rank_address < 30 THEN
1948 -- mark everything linked to this place for re-indexing
1949 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1950 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1951 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1953 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1954 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1956 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1957 b := deleteRoad(OLD.partition, OLD.place_id);
1959 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1960 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1961 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1962 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1963 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1967 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1969 IF OLD.rank_address < 26 THEN
1970 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1973 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1975 IF OLD.name is not null THEN
1976 b := deleteSearchName(OLD.partition, OLD.place_id);
1979 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1981 DELETE FROM place_addressline where place_id = OLD.place_id;
1983 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1985 -- remove from tables for special search
1986 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1987 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1989 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1992 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
2000 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2006 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2008 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2009 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2010 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;
2012 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2018 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;
2020 -- interpolations are special
2021 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2022 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2031 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2036 existingplacex RECORD;
2037 existingline RECORD;
2038 existinggeometry GEOMETRY;
2039 existingplace_id BIGINT;
2044 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2045 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2046 -- filter wrong tupels
2047 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
2048 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2049 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2050 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2054 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2055 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2056 -- Have we already done this place?
2057 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;
2059 -- Get the existing place_id
2060 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2062 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2063 IF existing.osm_type IS NULL THEN
2064 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2067 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2068 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2070 -- 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)
2071 IF existingline.osm_id IS NOT NULL THEN
2072 delete from location_property_osmline where osm_id = NEW.osm_id;
2075 -- for interpolations invalidate all nodes on the line
2076 update placex p set indexed_status = 2
2077 from planet_osm_ways w
2078 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2081 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2082 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2085 IF existing.osm_type IS NULL THEN
2089 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2090 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2091 OR existing.geometry::text != NEW.geometry::text
2096 address = NEW.address,
2097 extratags = NEW.extratags,
2098 admin_level = NEW.admin_level,
2099 geometry = NEW.geometry
2100 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2105 ELSE -- insert to placex
2107 -- Patch in additional country names
2108 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2109 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2110 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2111 IF existing.name IS NOT NULL THEN
2112 NEW.name = existing.name || NEW.name;
2116 -- Have we already done this place?
2117 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;
2119 -- Get the existing place_id
2120 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;
2122 -- Handle a place changing type by removing the old data
2123 -- My generated 'place' types are causing havok because they overlap with real keys
2124 -- TODO: move them to their own special purpose key/class to avoid collisions
2125 IF existing.osm_type IS NULL THEN
2126 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2129 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2130 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2133 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2134 AND st_area(existing.geometry) > 0.02
2135 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2136 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2138 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2139 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2140 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2144 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2145 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2147 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2148 IF existingplacex.osm_type IS NULL OR
2149 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2152 IF existingplacex.osm_type IS NOT NULL THEN
2153 -- sanity check: ignore admin_level changes on places with too many active children
2154 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2155 --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;
2156 --LIMIT INDEXING: IF i > 100000 THEN
2157 --LIMIT INDEXING: RETURN null;
2158 --LIMIT INDEXING: END IF;
2161 IF existing.osm_type IS NOT NULL THEN
2162 -- pathological case caused by the triggerless copy into place during initial import
2163 -- force delete even for large areas, it will be reinserted later
2164 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;
2165 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2168 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2169 insert into placex (osm_type, osm_id, class, type, name,
2170 admin_level, address, extratags, geometry)
2171 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2172 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2174 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2179 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2180 IF existing.geometry::text != NEW.geometry::text
2181 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2182 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2185 -- Get the version of the geometry actually used (in placex table)
2186 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;
2188 -- Performance limit
2189 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2191 -- 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
2192 update placex set indexed_status = 2 where indexed_status = 0 and
2193 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2194 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2195 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2197 update placex set indexed_status = 2 where indexed_status = 0 and
2198 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2199 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2200 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2207 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2208 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2209 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2210 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2211 OR existing.geometry::text != NEW.geometry::text
2216 address = NEW.address,
2217 extratags = NEW.extratags,
2218 admin_level = NEW.admin_level,
2219 geometry = NEW.geometry
2220 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2223 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2224 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2225 -- postcode was deleted, no longer retain in placex
2226 DELETE FROM placex where place_id = existingplacex.place_id;
2230 NEW.name := hstore('ref', NEW.address->'postcode');
2233 IF NEW.class in ('boundary')
2234 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2235 DELETE FROM placex where place_id = existingplacex.place_id;
2241 address = NEW.address,
2242 parent_place_id = null,
2243 extratags = NEW.extratags,
2244 admin_level = NEW.admin_level,
2246 geometry = NEW.geometry
2247 where place_id = existingplacex.place_id;
2249 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2250 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2251 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2252 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2253 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);
2256 -- linked places should get potential new naming and addresses
2257 IF existingplacex.linked_place_id is not NULL THEN
2260 extratags = p.extratags,
2263 where x.place_id = existingplacex.linked_place_id
2264 and x.indexed_status = 0
2265 and x.osm_type = p.osm_type
2266 and x.osm_id = p.osm_id
2267 and x.class = p.class;
2272 -- Abort the add (we modified the existing place instead)
2277 $$ LANGUAGE plpgsql;
2280 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2285 IF name is null THEN
2289 FOR j IN 1..array_upper(languagepref,1) LOOP
2290 IF name ? languagepref[j] THEN
2291 result := trim(name->languagepref[j]);
2292 IF result != '' THEN
2298 -- anything will do as a fallback - just take the first name type thing there is
2299 RETURN trim((avals(name))[1]);
2302 LANGUAGE plpgsql IMMUTABLE;
2305 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2316 search := ARRAY['ref'];
2319 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2322 select rank_address,name,distance,length(name::text) as namelength
2323 from place_addressline join placex on (address_place_id = placex.place_id)
2324 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2325 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2327 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2328 FOR j IN 1..array_upper(search, 1) LOOP
2329 FOR k IN 1..array_upper(location.name, 1) LOOP
2330 IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
2331 result[(100 - location.rank_address)] := trim(location.name[k].value);
2332 found := location.rank_address;
2339 RETURN array_to_string(result,', ');
2344 --housenumber only needed for tiger data
2345 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2357 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2358 currresult := trim(get_name_by_language(location.name, languagepref));
2359 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2360 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2361 prevresult := currresult;
2365 RETURN array_to_string(result,', ');
2370 DROP TYPE IF EXISTS addressline CASCADE;
2371 create type addressline as (
2378 admin_level INTEGER,
2381 rank_address INTEGER,
2385 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2388 for_place_id BIGINT;
2393 countrylocation RECORD;
2394 searchcountrycode varchar(2);
2395 searchhousenumber TEXT;
2396 searchhousename HSTORE;
2397 searchrankaddress INTEGER;
2398 searchpostcode TEXT;
2404 -- first query osmline (interpolation lines)
2405 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2406 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2407 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2408 IF for_place_id IS NOT NULL THEN
2409 searchhousenumber = in_housenumber::text;
2412 --then query tiger data
2413 -- %NOTIGERDATA% IF 0 THEN
2414 IF for_place_id IS NULL THEN
2415 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2416 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2417 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2418 IF for_place_id IS NOT NULL THEN
2419 searchhousenumber = in_housenumber::text;
2422 -- %NOTIGERDATA% END IF;
2424 -- %NOAUXDATA% IF 0 THEN
2425 IF for_place_id IS NULL THEN
2426 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2427 WHERE place_id = in_place_id
2428 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2430 -- %NOAUXDATA% END IF;
2432 IF for_place_id IS NULL THEN
2433 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2434 WHERE place_id = in_place_id and rank_search > 27
2435 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2438 IF for_place_id IS NULL THEN
2439 select coalesce(linked_place_id, place_id), country_code,
2440 housenumber, rank_search, postcode, null
2441 from placex where place_id = in_place_id
2442 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2445 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2448 hadcountry := false;
2450 select placex.place_id, osm_type, osm_id,
2451 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2452 class, type, admin_level, true as fromarea, true as isaddress,
2453 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2454 0 as distance, country_code, postcode
2456 where place_id = for_place_id
2458 --RAISE WARNING '%',location;
2459 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2460 searchcountrycode := location.country_code;
2462 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2463 location.isaddress := FALSE;
2465 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2466 searchpostcode := location.postcode;
2468 IF location.rank_address = 4 AND location.isaddress 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, location.fromarea, 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,
2487 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2488 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2489 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2490 admin_level, fromarea, isaddress,
2491 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,
2492 distance,country_code,postcode
2493 from place_addressline join placex on (address_place_id = placex.place_id)
2494 where place_addressline.place_id = for_place_id
2495 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2496 and address_place_id != for_place_id
2497 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2498 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2500 --RAISE WARNING '%',location;
2501 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2502 searchcountrycode := location.country_code;
2504 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2505 location.isaddress := FALSE;
2507 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL and location.postcode not similar to '%(,|;)%' THEN
2508 searchpostcode := location.postcode;
2510 IF location.rank_address = 4 AND location.isaddress THEN
2513 IF location.rank_address < 4 AND NOT hadcountry THEN
2514 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2515 IF countryname IS NOT NULL THEN
2516 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2517 RETURN NEXT countrylocation;
2520 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2521 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2522 location.distance)::addressline;
2523 RETURN NEXT countrylocation;
2524 found := location.rank_address;
2528 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2529 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2530 IF countryname IS NOT NULL THEN
2531 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2532 RETURN NEXT location;
2536 IF searchcountrycode IS NOT NULL THEN
2537 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2538 RETURN NEXT location;
2541 IF searchhousename IS NOT NULL THEN
2542 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2543 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2544 RETURN NEXT location;
2547 IF searchhousenumber IS NOT NULL THEN
2548 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2549 RETURN NEXT location;
2552 IF searchpostcode IS NOT NULL THEN
2553 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2554 RETURN NEXT location;
2563 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2569 ELSEIF rank < 4 THEN
2571 ELSEIF rank < 8 THEN
2573 ELSEIF rank < 12 THEN
2575 ELSEIF rank < 16 THEN
2577 ELSEIF rank = 16 THEN
2579 ELSEIF rank = 17 THEN
2580 RETURN 'Town / Island';
2581 ELSEIF rank = 18 THEN
2582 RETURN 'Village / Hamlet';
2583 ELSEIF rank = 20 THEN
2585 ELSEIF rank = 21 THEN
2586 RETURN 'Postcode Area';
2587 ELSEIF rank = 22 THEN
2588 RETURN 'Croft / Farm / Locality / Islet';
2589 ELSEIF rank = 23 THEN
2590 RETURN 'Postcode Area';
2591 ELSEIF rank = 25 THEN
2592 RETURN 'Postcode Point';
2593 ELSEIF rank = 26 THEN
2594 RETURN 'Street / Major Landmark';
2595 ELSEIF rank = 27 THEN
2596 RETURN 'Minory Street / Path';
2597 ELSEIF rank = 28 THEN
2598 RETURN 'House / Building';
2600 RETURN 'Other: '||rank;
2607 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2613 ELSEIF rank < 2 THEN
2615 ELSEIF rank < 4 THEN
2617 ELSEIF rank = 5 THEN
2619 ELSEIF rank < 8 THEN
2621 ELSEIF rank < 12 THEN
2623 ELSEIF rank < 16 THEN
2625 ELSEIF rank = 16 THEN
2627 ELSEIF rank = 17 THEN
2628 RETURN 'Town / Village / Hamlet';
2629 ELSEIF rank = 20 THEN
2631 ELSEIF rank = 21 THEN
2632 RETURN 'Postcode Area';
2633 ELSEIF rank = 22 THEN
2634 RETURN 'Croft / Farm / Locality / Islet';
2635 ELSEIF rank = 23 THEN
2636 RETURN 'Postcode Area';
2637 ELSEIF rank = 25 THEN
2638 RETURN 'Postcode Point';
2639 ELSEIF rank = 26 THEN
2640 RETURN 'Street / Major Landmark';
2641 ELSEIF rank = 27 THEN
2642 RETURN 'Minory Street / Path';
2643 ELSEIF rank = 28 THEN
2644 RETURN 'House / Building';
2646 RETURN 'Other: '||rank;
2653 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2654 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2659 place_centroid GEOMETRY;
2660 out_partition INTEGER;
2661 out_parent_place_id BIGINT;
2663 address_street_word_id INTEGER;
2668 place_centroid := ST_Centroid(pointgeo);
2669 out_partition := get_partition(in_countrycode);
2670 out_parent_place_id := null;
2672 address_street_word_id := get_name_id(make_standard_name(in_street));
2673 IF address_street_word_id IS NOT NULL THEN
2674 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2675 out_parent_place_id := location.place_id;
2679 IF out_parent_place_id IS NULL THEN
2680 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2681 out_parent_place_id := location.place_id;
2685 out_postcode := in_postcode;
2686 IF out_postcode IS NULL THEN
2687 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2689 -- XXX look into postcode table
2692 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2693 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2694 newpoints := newpoints + 1;
2701 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2708 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2709 IF members[i+1] = member THEN
2710 result := result || members[i];
2719 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2725 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2726 IF members[i+1] = ANY(memberLabels) THEN
2727 RETURN NEXT members[i];
2736 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2737 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2739 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2740 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
2741 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2742 ), '') AS bytea), 'UTF8');
2744 LANGUAGE SQL IMMUTABLE STRICT;
2746 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2750 RETURN decode_url_part(p);
2752 WHEN others THEN return null;
2755 LANGUAGE plpgsql IMMUTABLE;
2757 DROP TYPE wikipedia_article_match CASCADE;
2758 create type wikipedia_article_match as (
2764 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2770 wiki_article_title TEXT;
2771 wiki_article_language TEXT;
2772 result wikipedia_article_match;
2774 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'];
2776 WHILE langs[i] IS NOT NULL LOOP
2777 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2778 IF wiki_article is not null THEN
2779 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2780 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2781 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2782 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2783 wiki_article := replace(wiki_article,' ','_');
2784 IF strpos(wiki_article, ':') IN (3,4) THEN
2785 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2786 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2788 wiki_article_title := trim(wiki_article);
2789 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;
2792 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2793 from wikipedia_article
2794 where language = wiki_article_language and
2795 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2797 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2798 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2799 where wikipedia_redirect.language = wiki_article_language and
2800 (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'\\',''))
2801 order by importance desc limit 1 INTO result;
2803 IF result.language is not null THEN
2814 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2815 RETURNS SETOF GEOMETRY
2829 remainingdepth INTEGER;
2834 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2836 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2837 RETURN NEXT geometry;
2841 remainingdepth := maxdepth - 1;
2842 area := ST_AREA(geometry);
2843 IF remainingdepth < 1 OR area < maxarea THEN
2844 RETURN NEXT geometry;
2848 xmin := st_xmin(geometry);
2849 xmax := st_xmax(geometry);
2850 ymin := st_ymin(geometry);
2851 ymax := st_ymax(geometry);
2852 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2854 -- if the geometry completely covers the box don't bother to slice any more
2855 IF ST_AREA(secbox) = area THEN
2856 RETURN NEXT geometry;
2860 xmid := (xmin+xmax)/2;
2861 ymid := (ymin+ymax)/2;
2864 FOR seg IN 1..4 LOOP
2867 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2870 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2873 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2876 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2879 IF st_intersects(geometry, secbox) THEN
2880 secgeo := st_intersection(geometry, secbox);
2881 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2882 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2883 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2885 RETURN NEXT geo.geom;
2897 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2898 RETURNS SETOF GEOMETRY
2903 -- 10000000000 is ~~ 1x1 degree
2904 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2905 RETURN NEXT geo.geom;
2913 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2917 osmtype character(1);
2921 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2922 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2923 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2924 -- force delete from place/placex by making it a very small geometry
2925 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;
2926 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2933 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2941 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2942 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2943 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2944 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2945 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2946 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2947 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'));
2948 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2949 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'));
2955 ELSEIF rank < 18 THEN
2957 ELSEIF rank < 20 THEN
2959 ELSEIF rank = 21 THEN
2961 ELSEIF rank < 24 THEN
2963 ELSEIF rank < 26 THEN
2964 diameter := 0.002; -- 100 to 200 meters
2965 ELSEIF rank < 28 THEN
2966 diameter := 0.001; -- 50 to 100 meters
2968 IF diameter > 0 THEN
2970 -- roads may cause reparenting for >27 rank places
2971 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2972 ELSEIF rank >= 16 THEN
2973 -- up to rank 16, street-less addresses may need reparenting
2974 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');
2976 -- for all other places the search terms may change as well
2977 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);