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,
591 IF rank_search > 25 THEN
592 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
595 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
597 x := deleteLocationArea(partition, place_id, rank_search);
600 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
603 centroid := ST_Centroid(geometry);
605 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
606 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
612 IF rank_address = 0 THEN
614 ELSEIF rank_search <= 14 THEN
616 ELSEIF rank_search <= 15 THEN
618 ELSEIF rank_search <= 16 THEN
620 ELSEIF rank_search <= 17 THEN
622 ELSEIF rank_search <= 21 THEN
624 ELSEIF rank_search = 25 THEN
628 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
630 secgeo := ST_Buffer(geometry, diameter);
631 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
641 -- find the parent road of the cut road parts
642 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
643 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
648 parent_place_id BIGINT;
649 address_street_word_ids INTEGER[];
655 addr_street = street;
658 IF addr_street is null and addr_place is null THEN
659 select nodes from planet_osm_ways where id = wayid INTO waynodes;
660 FOR location IN SELECT placex.address from placex
661 where osm_type = 'N' and osm_id = ANY(waynodes)
662 and placex.address is not null
663 and (placex.address ? 'street' or placex.address ? 'place')
664 and indexed_status < 100
666 addr_street = location.address->'street';
667 addr_place = location.address->'place';
671 IF addr_street IS NOT NULL THEN
672 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
673 IF address_street_word_ids IS NOT NULL THEN
674 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
675 parent_place_id := location.place_id;
680 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
681 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
682 IF address_street_word_ids IS NOT NULL THEN
683 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
684 parent_place_id := location.place_id;
689 IF parent_place_id is null THEN
690 FOR location IN SELECT place_id FROM placex
691 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
692 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
693 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
694 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
696 parent_place_id := location.place_id;
700 IF parent_place_id is null THEN
704 RETURN parent_place_id;
710 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
713 NEW.place_id := nextval('seq_place');
714 NEW.indexed_date := now();
716 IF NEW.indexed_status IS NULL THEN
717 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
718 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
719 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
723 NEW.indexed_status := 1; --STATUS_NEW
724 NEW.country_code := lower(get_country_code(NEW.linegeo));
726 NEW.partition := get_partition(NEW.country_code);
727 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
736 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
742 country_code VARCHAR(2);
743 default_language VARCHAR(10);
748 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
750 NEW.place_id := nextval('seq_place');
751 NEW.indexed_status := 1; --STATUS_NEW
753 NEW.country_code := lower(get_country_code(NEW.geometry));
755 NEW.partition := get_partition(NEW.country_code);
756 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
758 -- copy 'name' to or from the default language (if there is a default language)
759 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
760 default_language := get_country_language_code(NEW.country_code);
761 IF default_language IS NOT NULL THEN
762 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
763 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
764 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
765 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
770 IF NEW.osm_type = 'X' THEN
771 -- E'X'ternal records should already be in the right format so do nothing
773 NEW.rank_search := 30;
774 NEW.rank_address := NEW.rank_search;
776 -- By doing in postgres we have the country available to us - currently only used for postcode
777 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
779 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
780 -- most likely just a part of a multipolygon postcode boundary, throw it away
784 NEW.postcode := NEW.address->'postcode';
785 NEW.name := hstore('ref', NEW.postcode);
787 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
788 INTO NEW.rank_search, NEW.rank_address;
790 ELSEIF NEW.class = 'place' THEN
791 IF NEW.type in ('continent') THEN
792 NEW.rank_search := 2;
793 NEW.rank_address := NEW.rank_search;
794 NEW.country_code := NULL;
795 ELSEIF NEW.type in ('sea') THEN
796 NEW.rank_search := 2;
797 NEW.rank_address := 0;
798 NEW.country_code := NULL;
799 ELSEIF NEW.type in ('country') THEN
800 NEW.rank_search := 4;
801 NEW.rank_address := NEW.rank_search;
802 ELSEIF NEW.type in ('state') THEN
803 NEW.rank_search := 8;
804 NEW.rank_address := NEW.rank_search;
805 ELSEIF NEW.type in ('region') THEN
806 NEW.rank_search := 18; -- dropped from previous value of 10
807 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
808 ELSEIF NEW.type in ('county') THEN
809 NEW.rank_search := 12;
810 NEW.rank_address := NEW.rank_search;
811 ELSEIF NEW.type in ('city') THEN
812 NEW.rank_search := 16;
813 NEW.rank_address := NEW.rank_search;
814 ELSEIF NEW.type in ('island') THEN
815 NEW.rank_search := 17;
816 NEW.rank_address := 0;
817 ELSEIF NEW.type in ('town') THEN
818 NEW.rank_search := 18;
819 NEW.rank_address := 16;
820 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
821 NEW.rank_search := 19;
822 NEW.rank_address := 16;
823 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
824 NEW.rank_search := 20;
825 NEW.rank_address := NEW.rank_search;
826 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
827 NEW.rank_search := 20;
828 NEW.rank_address := 0;
829 -- Irish townlands, tagged as place=locality and locality=townland
830 IF (NEW.extratags -> 'locality') = 'townland' THEN
831 NEW.rank_address := 20;
833 ELSEIF NEW.type in ('neighbourhood') THEN
834 NEW.rank_search := 22;
835 NEW.rank_address := 22;
836 ELSEIF NEW.type in ('house','building') THEN
837 NEW.rank_search := 30;
838 NEW.rank_address := NEW.rank_search;
839 ELSEIF NEW.type in ('houses') THEN
840 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
841 NEW.rank_search := 28;
842 NEW.rank_address := 0;
845 ELSEIF NEW.class = 'boundary' THEN
846 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
847 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
850 NEW.rank_search := NEW.admin_level * 2;
851 IF NEW.type = 'administrative' THEN
852 NEW.rank_address := NEW.rank_search;
854 NEW.rank_address := 0;
856 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
857 NEW.rank_search := 22;
858 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
859 NEW.rank_address := NEW.rank_search;
861 NEW.rank_address := 0;
863 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
864 NEW.rank_search := 18;
865 NEW.rank_address := 0;
866 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
867 NEW.rank_search := 4;
868 NEW.rank_address := NEW.rank_search;
869 -- any feature more than 5 square miles is probably worth indexing
870 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
871 NEW.rank_search := 22;
872 NEW.rank_address := 0;
873 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
875 ELSEIF NEW.class = 'waterway' THEN
876 IF NEW.osm_type = 'R' THEN
877 NEW.rank_search := 16;
879 NEW.rank_search := 17;
881 NEW.rank_address := 0;
882 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
883 NEW.rank_search := 27;
884 NEW.rank_address := NEW.rank_search;
885 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
886 NEW.rank_search := 26;
887 NEW.rank_address := NEW.rank_search;
888 ELSEIF NEW.class = 'mountain_pass' THEN
889 NEW.rank_search := 20;
890 NEW.rank_address := 0;
895 IF NEW.rank_search > 30 THEN
896 NEW.rank_search := 30;
899 IF NEW.rank_address > 30 THEN
900 NEW.rank_address := 30;
903 IF (NEW.extratags -> 'capital') = 'yes' THEN
904 NEW.rank_search := NEW.rank_search - 1;
907 -- a country code make no sense below rank 4 (country)
908 IF NEW.rank_search < 4 THEN
909 NEW.country_code := NULL;
912 -- Block import below rank 22
913 -- IF NEW.rank_search > 22 THEN
917 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
919 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
921 IF NEW.rank_address > 0 THEN
922 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
923 -- Performance: We just can't handle re-indexing for country level changes
924 IF st_area(NEW.geometry) < 1 THEN
925 -- mark items within the geometry for re-indexing
926 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
928 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
929 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
930 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'));
931 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
932 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'));
935 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
937 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
938 IF NEW.type='postcode' THEN
940 ELSEIF NEW.rank_search < 16 THEN
942 ELSEIF NEW.rank_search < 18 THEN
944 ELSEIF NEW.rank_search < 20 THEN
946 ELSEIF NEW.rank_search = 21 THEN
948 ELSEIF NEW.rank_search < 24 THEN
950 ELSEIF NEW.rank_search < 26 THEN
951 diameter := 0.002; -- 100 to 200 meters
952 ELSEIF NEW.rank_search < 28 THEN
953 diameter := 0.001; -- 50 to 100 meters
956 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
957 IF NEW.rank_search >= 26 THEN
958 -- roads may cause reparenting for >27 rank places
959 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
960 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
961 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
962 ELSEIF NEW.rank_search >= 16 THEN
963 -- up to rank 16, street-less addresses may need reparenting
964 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');
966 -- for all other places the search terms may change as well
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);
974 -- add to tables for special search
975 -- Note: won't work on initial import because the classtype tables
976 -- do not yet exist. It won't hurt either.
977 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
978 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
980 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
981 USING NEW.place_id, ST_Centroid(NEW.geometry);
990 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
994 place_centroid GEOMETRY;
1003 sectiongeo GEOMETRY;
1008 IF OLD.indexed_status = 100 THEN
1009 delete from location_property_osmline where place_id = OLD.place_id;
1013 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1017 NEW.interpolationtype = NEW.address->'interpolation';
1019 place_centroid := ST_PointOnSurface(NEW.linegeo);
1020 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1021 NEW.address->'place',
1022 NEW.partition, place_centroid, NEW.linegeo);
1025 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1026 NEW.postcode = NEW.address->'postcode';
1029 -- if the line was newly inserted, split the line as necessary
1030 IF OLD.indexed_status = 1 THEN
1031 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1033 IF array_upper(waynodes, 1) IS NULL THEN
1037 linegeo := NEW.linegeo;
1038 startnumber := NULL;
1039 postcode := NEW.postcode;
1041 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1043 select osm_id, address, geometry
1044 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1045 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1046 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1047 IF nextnode.osm_id IS NOT NULL THEN
1048 --RAISE NOTICE 'place_id is not null';
1049 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1050 -- Make sure that the point is actually on the line. That might
1051 -- be a bit paranoid but ensures that the algorithm still works
1052 -- should osm2pgsql attempt to repair geometries.
1053 splitline := split_line_on_node(linegeo, nextnode.geometry);
1054 sectiongeo := ST_GeometryN(splitline, 1);
1055 linegeo := ST_GeometryN(splitline, 2);
1057 sectiongeo = linegeo;
1059 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1061 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1062 AND startnumber != endnumber
1063 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1065 IF (startnumber > endnumber) THEN
1066 housenum := endnumber;
1067 endnumber := startnumber;
1068 startnumber := housenum;
1069 sectiongeo := ST_Reverse(sectiongeo);
1072 seg_postcode := coalesce(postcode,
1073 prevnode.address->'postcode',
1074 nextnode.address->'postcode');
1076 IF NEW.startnumber IS NULL THEN
1077 NEW.startnumber := startnumber;
1078 NEW.endnumber := endnumber;
1079 NEW.linegeo := sectiongeo;
1080 NEW.postcode := seg_postcode;
1082 insert into location_property_osmline
1083 (linegeo, partition, osm_id, parent_place_id,
1084 startnumber, endnumber, interpolationtype,
1085 address, postcode, country_code,
1086 geometry_sector, indexed_status)
1087 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1088 startnumber, endnumber, NEW.interpolationtype,
1089 NEW.address, seg_postcode,
1090 NEW.country_code, NEW.geometry_sector, 0);
1094 -- early break if we are out of line string,
1095 -- might happen when a line string loops back on itself
1096 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1100 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1101 prevnode := nextnode;
1106 -- marking descendants for reparenting is not needed, because there are
1107 -- actually no descendants for interpolation lines
1113 -- Trigger for updates of location_postcode
1115 -- Computes the parent object the postcode most likely refers to.
1116 -- This will be the place that determines the address displayed when
1117 -- searching for this postcode.
1118 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1125 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1129 NEW.indexed_date = now();
1131 partition := get_partition(NEW.country_code);
1133 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1134 INTO NEW.rank_search, NEW.rank_address;
1136 NEW.parent_place_id = 0;
1139 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1140 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1142 NEW.parent_place_id = location.place_id;
1150 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1155 place_centroid GEOMETRY;
1157 search_maxdistance FLOAT[];
1158 search_mindistance FLOAT[];
1159 address_havelevel BOOLEAN[];
1166 relation_members TEXT[];
1168 linkedplacex RECORD;
1169 search_diameter FLOAT;
1170 search_prevdiameter FLOAT;
1171 search_maxrank INTEGER;
1172 address_maxrank INTEGER;
1173 address_street_word_id INTEGER;
1174 address_street_word_ids INTEGER[];
1175 parent_place_id_rank BIGINT;
1183 location_rank_search INTEGER;
1184 location_distance FLOAT;
1185 location_parent GEOMETRY;
1186 location_isaddress BOOLEAN;
1187 location_keywords INTEGER[];
1189 default_language TEXT;
1190 name_vector INTEGER[];
1191 nameaddress_vector INTEGER[];
1193 linked_node_id BIGINT;
1194 linked_importance FLOAT;
1195 linked_wikipedia TEXT;
1200 IF OLD.indexed_status = 100 THEN
1201 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1202 delete from placex where place_id = OLD.place_id;
1206 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1210 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1212 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1213 -- Silently do nothing
1217 NEW.indexed_date = now();
1219 result := deleteSearchName(NEW.partition, NEW.place_id);
1220 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1221 result := deleteRoad(NEW.partition, NEW.place_id);
1222 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1223 UPDATE placex set linked_place_id = null, indexed_status = 2
1224 where linked_place_id = NEW.place_id;
1225 -- update not necessary for osmline, cause linked_place_id does not exist
1227 IF NEW.linked_place_id is not null THEN
1228 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1232 --DEBUG: RAISE WARNING 'Copy over address tags';
1233 IF NEW.address is not NULL THEN
1234 IF NEW.address ? 'conscriptionnumber' THEN
1235 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1236 IF NEW.address ? 'streetnumber' THEN
1237 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1238 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1240 NEW.housenumber := NEW.address->'conscriptionnumber';
1242 ELSEIF NEW.address ? 'streetnumber' THEN
1243 NEW.housenumber := NEW.address->'streetnumber';
1244 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1245 ELSEIF NEW.address ? 'housenumber' THEN
1246 NEW.housenumber := NEW.address->'housenumber';
1247 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1250 addr_street = NEW.address->'street';
1251 addr_place = NEW.address->'place';
1253 NEW.postcode = NEW.address->'postcode';
1256 -- Speed up searches - just use the centroid of the feature
1257 -- cheaper but less acurate
1258 place_centroid := ST_PointOnSurface(NEW.geometry);
1259 NEW.centroid := null;
1260 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1262 -- recalculate country and partition
1263 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1264 -- for countries, believe the mapped country code,
1265 -- so that we remain in the right partition if the boundaries
1267 NEW.country_code := lower(NEW.address->'country');
1268 NEW.partition := get_partition(lower(NEW.country_code));
1269 IF NEW.partition = 0 THEN
1270 NEW.country_code := lower(get_country_code(place_centroid));
1271 NEW.partition := get_partition(NEW.country_code);
1274 IF NEW.rank_search >= 4 THEN
1275 NEW.country_code := lower(get_country_code(place_centroid));
1277 NEW.country_code := NULL;
1279 NEW.partition := get_partition(NEW.country_code);
1281 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1283 -- waterway ways are linked when they are part of a relation and have the same class/type
1284 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1285 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1287 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1288 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1289 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1290 FOR linked_node_id IN SELECT place_id FROM placex
1291 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1292 and class = NEW.class and type = NEW.type
1293 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1295 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1300 --DEBUG: RAISE WARNING 'Waterway processed';
1303 -- Adding ourselves to the list simplifies address calculations later
1304 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1305 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1307 -- What level are we searching from
1308 search_maxrank := NEW.rank_search;
1310 -- Thought this wasn't needed but when we add new languages to the country_name table
1311 -- we need to update the existing names
1312 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1313 default_language := get_country_language_code(NEW.country_code);
1314 IF default_language IS NOT NULL THEN
1315 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1316 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1317 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1318 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1322 --DEBUG: RAISE WARNING 'Local names updated';
1324 -- Initialise the name vector using our name
1325 name_vector := make_keywords(NEW.name);
1326 nameaddress_vector := '{}'::int[];
1329 address_havelevel[i] := false;
1332 NEW.importance := null;
1333 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1334 IF NEW.importance IS NULL THEN
1335 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;
1338 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1340 -- ---------------------------------------------------------------------------
1341 -- For low level elements we inherit from our parent road
1342 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1344 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1346 -- We won't get a better centroid, besides these places are too small to care
1347 NEW.centroid := place_centroid;
1349 NEW.parent_place_id := null;
1351 -- if we have a POI and there is no address information,
1352 -- see if we can get it from a surrounding building
1353 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1354 AND NEW.housenumber IS NULL THEN
1355 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1356 and address is not null
1357 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1358 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1361 NEW.housenumber := location.address->'housenumber';
1362 addr_street := location.address->'street';
1363 addr_place := location.address->'place';
1364 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1368 -- We have to find our parent road.
1369 -- Copy data from linked items (points on ways, addr:street links, relations)
1371 -- Is this object part of a relation?
1372 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1374 -- At the moment we only process one type of relation - associatedStreet
1375 IF relation.tags @> ARRAY['associatedStreet'] THEN
1376 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1377 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1378 --RAISE WARNING 'node in relation %',relation;
1379 SELECT place_id from placex where osm_type = 'W'
1380 and osm_id = substring(relation.members[i],2,200)::bigint
1381 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1386 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1388 -- Note that addr:street links can only be indexed once the street itself is indexed
1389 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1390 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1391 IF address_street_word_ids IS NOT NULL THEN
1392 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1393 NEW.parent_place_id := location.place_id;
1397 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1399 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1400 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1401 IF address_street_word_ids IS NOT NULL THEN
1402 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1403 NEW.parent_place_id := location.place_id;
1407 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1409 -- Is this node part of an interpolation?
1410 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1412 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1413 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1416 NEW.parent_place_id := location.parent_place_id;
1419 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1421 -- Is this node part of a way?
1422 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1424 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
1425 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)
1427 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1429 -- Way IS a road then we are on it - that must be our road
1430 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1431 --RAISE WARNING 'node in way that is a street %',location;
1432 NEW.parent_place_id := location.place_id;
1434 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1436 -- If the way mentions a street or place address, try that for parenting.
1437 IF NEW.parent_place_id IS NULL AND location.address ? 'street' THEN
1438 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1439 IF address_street_word_ids IS NOT NULL THEN
1440 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1441 NEW.parent_place_id := linkedplacex.place_id;
1445 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1447 IF NEW.parent_place_id IS NULL AND location.address ? 'place' THEN
1448 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1449 IF address_street_word_ids IS NOT NULL THEN
1450 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1451 NEW.parent_place_id := linkedplacex.place_id;
1455 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1457 -- Is the WAY part of a relation
1458 IF NEW.parent_place_id IS NULL THEN
1459 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1461 -- At the moment we only process one type of relation - associatedStreet
1462 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1463 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1464 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1465 --RAISE WARNING 'node in way that is in a relation %',relation;
1466 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1467 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1473 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1479 -- Still nothing, just use the nearest road
1480 IF NEW.parent_place_id IS NULL THEN
1481 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1482 NEW.parent_place_id := location.place_id;
1485 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1488 -- If we didn't find any road fallback to standard method
1489 IF NEW.parent_place_id IS NOT NULL THEN
1491 -- Get the details of the parent road
1492 select * from search_name where place_id = NEW.parent_place_id INTO location;
1493 NEW.country_code := location.country_code;
1494 --DEBUG: RAISE WARNING 'Got parent details from search name';
1496 -- Merge the postcode into the parent's address if necessary
1497 IF NEW.postcode IS NOT NULL THEN
1498 --DEBUG: RAISE WARNING 'Merging postcode into parent';
1499 isin_tokens := '{}'::int[];
1500 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1501 IF address_street_word_id is not null
1502 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1503 isin_tokens := isin_tokens || address_street_word_id;
1505 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1506 IF address_street_word_id is not null
1507 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1508 isin_tokens := isin_tokens || address_street_word_id;
1510 IF isin_tokens != '{}'::int[] THEN
1512 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1513 WHERE place_id = NEW.parent_place_id;
1517 -- If there is no name it isn't searchable, don't bother to create a search record
1518 IF NEW.name is NULL THEN
1519 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1523 -- Merge address from parent
1524 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1525 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1527 -- Performance, it would be more acurate to do all the rest of the import
1528 -- process but it takes too long
1529 -- Just be happy with inheriting from parent road only
1531 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1532 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1533 --DEBUG: RAISE WARNING 'Place added to location table';
1536 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);
1537 --DEBUG: RAISE WARNING 'Place added to search table';
1544 -- ---------------------------------------------------------------------------
1546 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1548 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1550 -- see if we have any special relation members
1551 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1552 --DEBUG: RAISE WARNING 'Got relation members';
1554 IF relation_members IS NOT NULL THEN
1555 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1556 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1558 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1559 and osm_id = substring(relMember.member,2,10000)::bigint
1560 and class = 'place' order by rank_search desc limit 1 LOOP
1562 -- If we don't already have one use this as the centre point of the geometry
1563 IF NEW.centroid IS NULL THEN
1564 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1567 -- merge in the label name, re-init word vector
1568 IF NOT linkedPlacex.name IS NULL THEN
1569 NEW.name := linkedPlacex.name || NEW.name;
1570 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1573 -- merge in extra tags
1574 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1576 -- mark the linked place (excludes from search results)
1577 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1579 -- keep a note of the node id in case we need it for wikipedia in a bit
1580 linked_node_id := linkedPlacex.osm_id;
1581 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1582 --DEBUG: RAISE WARNING 'Linked label member';
1587 IF NEW.centroid IS NULL THEN
1589 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1590 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1592 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1593 and osm_id = substring(relMember.member,2,10000)::bigint
1594 and class = 'place' order by rank_search desc limit 1 LOOP
1596 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1597 -- But that can be fixed by explicitly setting the label in the data
1598 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1599 AND NEW.rank_address = linkedPlacex.rank_address THEN
1601 -- If we don't already have one use this as the centre point of the geometry
1602 IF NEW.centroid IS NULL THEN
1603 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1606 -- merge in the name, re-init word vector
1607 IF NOT linkedPlacex.name IS NULL THEN
1608 NEW.name := linkedPlacex.name || NEW.name;
1609 name_vector := make_keywords(NEW.name);
1612 -- merge in extra tags
1613 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1615 -- mark the linked place (excludes from search results)
1616 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1618 -- keep a note of the node id in case we need it for wikipedia in a bit
1619 linked_node_id := linkedPlacex.osm_id;
1620 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1621 --DEBUG: RAISE WARNING 'Linked admin_center';
1633 -- Name searches can be done for ways as well as relations
1634 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1636 -- not found one yet? how about doing a name search
1637 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1639 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1640 FOR linkedPlacex IN select placex.* from placex WHERE
1641 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1642 AND placex.rank_address = NEW.rank_address
1643 AND placex.place_id != NEW.place_id
1644 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1645 AND st_covers(NEW.geometry, placex.geometry)
1647 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1648 -- If we don't already have one use this as the centre point of the geometry
1649 IF NEW.centroid IS NULL THEN
1650 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1653 -- merge in the name, re-init word vector
1654 NEW.name := linkedPlacex.name || NEW.name;
1655 name_vector := make_keywords(NEW.name);
1657 -- merge in extra tags
1658 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1660 -- mark the linked place (excludes from search results)
1661 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1663 -- keep a note of the node id in case we need it for wikipedia in a bit
1664 linked_node_id := linkedPlacex.osm_id;
1665 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1666 --DEBUG: RAISE WARNING 'Linked named place';
1670 IF NEW.centroid IS NOT NULL THEN
1671 place_centroid := NEW.centroid;
1672 -- Place might have had only a name tag before but has now received translations
1673 -- from the linked place. Make sure a name tag for the default language exists in
1675 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1676 default_language := get_country_language_code(NEW.country_code);
1677 IF default_language IS NOT NULL THEN
1678 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1679 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1680 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1681 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1685 --DEBUG: RAISE WARNING 'Names updated from linked places';
1688 -- Use the maximum importance if a one could be computed from the linked object.
1689 IF linked_importance is not null AND
1690 (NEW.importance is null or NEW.importance < linked_importance) THEN
1691 NEW.importance = linked_importance;
1694 -- Still null? how about looking it up by the node id
1695 IF NEW.importance IS NULL THEN
1696 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1697 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;
1702 -- make sure all names are in the word table
1703 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1704 perform create_country(NEW.name, lower(NEW.country_code));
1705 --DEBUG: RAISE WARNING 'Country names updated';
1708 NEW.parent_place_id = 0;
1709 parent_place_id_rank = 0;
1712 -- convert isin to array of tokenids
1713 --DEBUG: RAISE WARNING 'Starting address search';
1714 isin_tokens := '{}'::int[];
1715 IF NEW.address IS NOT NULL THEN
1716 isin := avals(NEW.address);
1717 IF array_upper(isin, 1) IS NOT NULL THEN
1718 FOR i IN 1..array_upper(isin, 1) LOOP
1719 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1720 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1721 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1722 isin_tokens := isin_tokens || address_street_word_id;
1725 -- merge word into address vector
1726 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1727 IF address_street_word_id IS NOT NULL THEN
1728 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1733 --DEBUG: RAISE WARNING '"address:* tokens collected';
1734 IF NEW.postcode IS NOT NULL THEN
1735 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1736 IF array_upper(isin, 1) IS NOT NULL THEN
1737 FOR i IN 1..array_upper(isin, 1) LOOP
1738 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1739 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1740 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1741 isin_tokens := isin_tokens || address_street_word_id;
1744 -- merge into address vector
1745 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1746 IF address_street_word_id IS NOT NULL THEN
1747 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1752 --DEBUG: RAISE WARNING 'postcode tokens collected';
1754 -- %NOTIGERDATA% IF 0 THEN
1755 -- for the USA we have an additional address table. Merge in zip codes from there too
1756 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1757 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1758 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1759 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1760 isin_tokens := isin_tokens || address_street_word_id;
1762 -- also merge in the single word version
1763 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1764 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1767 --DEBUG: RAISE WARNING 'Tiger postcodes collected';
1768 -- %NOTIGERDATA% END IF;
1770 -- RAISE WARNING 'ISIN: %', isin_tokens;
1772 -- Process area matches
1773 location_rank_search := 0;
1774 location_distance := 0;
1775 location_parent := NULL;
1776 -- added ourself as address already
1777 address_havelevel[NEW.rank_address] := true;
1778 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1780 SELECT * from getNearFeatures(NEW.partition,
1781 CASE WHEN NEW.rank_search >= 26
1782 AND NEW.rank_search < 30
1784 ELSE place_centroid END,
1785 search_maxrank, isin_tokens)
1787 IF location.rank_address != location_rank_search THEN
1788 location_rank_search := location.rank_address;
1789 IF location.isguess THEN
1790 location_distance := location.distance * 1.5;
1792 IF location.rank_address <= 12 THEN
1793 -- for county and above, if we have an area consider that exact
1794 -- (It would be nice to relax the constraint for places close to
1795 -- the boundary but we'd need the exact geometry for that. Too
1797 location_distance = 0;
1799 -- Below county level remain slightly fuzzy.
1800 location_distance := location.distance * 0.5;
1804 CONTINUE WHEN location.keywords <@ location_keywords;
1807 IF location.distance < location_distance OR NOT location.isguess THEN
1808 location_keywords := location.keywords;
1810 location_isaddress := NOT address_havelevel[location.rank_address];
1811 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1812 location_isaddress := ST_Contains(location_parent,location.centroid);
1815 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1816 -- Add it to the list of search terms
1817 IF location.rank_search > 4 THEN
1818 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1820 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1821 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1823 IF location_isaddress THEN
1825 address_havelevel[location.rank_address] := true;
1826 IF NOT location.isguess THEN
1827 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1830 IF location.rank_address > parent_place_id_rank THEN
1831 NEW.parent_place_id = location.place_id;
1832 parent_place_id_rank = location.rank_address;
1837 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1842 --DEBUG: RAISE WARNING 'address computed';
1844 -- try using the isin value to find parent places
1845 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1846 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1847 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1848 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1850 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1852 --RAISE WARNING ' ISIN: %',location;
1854 IF location.rank_search > 4 THEN
1855 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1856 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1857 VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1858 address_havelevel[location.rank_address] := true;
1860 IF location.rank_address > parent_place_id_rank THEN
1861 NEW.parent_place_id = location.place_id;
1862 parent_place_id_rank = location.rank_address;
1871 --DEBUG: RAISE WARNING 'isin tokens processed';
1873 -- for long ways we should add search terms for the entire length
1874 IF st_length(NEW.geometry) > 0.05 THEN
1876 location_rank_search := 0;
1877 location_distance := 0;
1879 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1881 IF location.rank_address != location_rank_search THEN
1882 location_rank_search := location.rank_address;
1883 location_distance := location.distance * 1.5;
1886 IF location.rank_search > 4 AND location.distance < location_distance THEN
1888 -- Add it to the list of search terms
1889 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1890 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1891 VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1898 --DEBUG: RAISE WARNING 'search terms for long ways added';
1900 -- if we have a name add this to the name search table
1901 IF NEW.name IS NOT NULL THEN
1903 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1904 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1905 --DEBUG: RAISE WARNING 'added to location (full)';
1908 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1909 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1910 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1913 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);
1914 --DEBUG: RAISE WARNING 'added to serach name (full)';
1918 -- If we've not managed to pick up a better one - default centroid
1919 IF NEW.centroid IS NULL THEN
1920 NEW.centroid := place_centroid;
1923 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1930 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1936 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1938 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1939 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1940 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1941 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1943 IF OLD.rank_address < 30 THEN
1945 -- mark everything linked to this place for re-indexing
1946 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1947 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1948 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1950 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1951 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1953 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1954 b := deleteRoad(OLD.partition, OLD.place_id);
1956 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1957 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1958 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1959 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1960 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1964 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1966 IF OLD.rank_address < 26 THEN
1967 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1970 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1972 IF OLD.name is not null THEN
1973 b := deleteSearchName(OLD.partition, OLD.place_id);
1976 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1978 DELETE FROM place_addressline where place_id = OLD.place_id;
1980 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1982 -- remove from tables for special search
1983 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1984 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1986 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1989 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1997 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
2003 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
2005 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
2006 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
2007 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;
2009 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
2015 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;
2017 -- interpolations are special
2018 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2019 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2028 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2033 existingplacex RECORD;
2034 existingline RECORD;
2035 existinggeometry GEOMETRY;
2036 existingplace_id BIGINT;
2041 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2042 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2043 -- filter wrong tupels
2044 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
2045 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2046 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2047 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2051 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2052 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2053 -- Have we already done this place?
2054 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;
2056 -- Get the existing place_id
2057 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2059 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2060 IF existing.osm_type IS NULL THEN
2061 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2064 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2065 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2067 -- 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)
2068 IF existingline.osm_id IS NOT NULL THEN
2069 delete from location_property_osmline where osm_id = NEW.osm_id;
2072 -- for interpolations invalidate all nodes on the line
2073 update placex p set indexed_status = 2
2074 from planet_osm_ways w
2075 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2078 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2079 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2082 IF existing.osm_type IS NULL THEN
2086 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2087 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2088 OR existing.geometry::text != NEW.geometry::text
2093 address = NEW.address,
2094 extratags = NEW.extratags,
2095 admin_level = NEW.admin_level,
2096 geometry = NEW.geometry
2097 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2102 ELSE -- insert to placex
2104 -- Patch in additional country names
2105 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2106 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2107 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2108 IF existing.name IS NOT NULL THEN
2109 NEW.name = existing.name || NEW.name;
2113 -- Have we already done this place?
2114 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;
2116 -- Get the existing place_id
2117 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;
2119 -- Handle a place changing type by removing the old data
2120 -- My generated 'place' types are causing havok because they overlap with real keys
2121 -- TODO: move them to their own special purpose key/class to avoid collisions
2122 IF existing.osm_type IS NULL THEN
2123 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2126 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2127 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2130 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2131 AND st_area(existing.geometry) > 0.02
2132 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2133 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2135 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2136 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2137 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2141 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2142 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2144 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2145 IF existingplacex.osm_type IS NULL OR
2146 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2149 IF existingplacex.osm_type IS NOT NULL THEN
2150 -- sanity check: ignore admin_level changes on places with too many active children
2151 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2152 --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;
2153 --LIMIT INDEXING: IF i > 100000 THEN
2154 --LIMIT INDEXING: RETURN null;
2155 --LIMIT INDEXING: END IF;
2158 IF existing.osm_type IS NOT NULL THEN
2159 -- pathological case caused by the triggerless copy into place during initial import
2160 -- force delete even for large areas, it will be reinserted later
2161 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;
2162 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2165 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2166 insert into placex (osm_type, osm_id, class, type, name,
2167 admin_level, address, extratags, geometry)
2168 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2169 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2171 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2176 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2177 IF existing.geometry::text != NEW.geometry::text
2178 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2179 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2182 -- Get the version of the geometry actually used (in placex table)
2183 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;
2185 -- Performance limit
2186 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2188 -- 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
2189 update placex set indexed_status = 2 where indexed_status = 0 and
2190 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2191 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2192 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2194 update placex set indexed_status = 2 where indexed_status = 0 and
2195 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2196 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2197 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2204 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2205 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2206 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2207 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2208 OR existing.geometry::text != NEW.geometry::text
2213 address = NEW.address,
2214 extratags = NEW.extratags,
2215 admin_level = NEW.admin_level,
2216 geometry = NEW.geometry
2217 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2220 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2221 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2222 -- postcode was deleted, no longer retain in placex
2223 DELETE FROM placex where place_id = existingplacex.place_id;
2227 NEW.name := hstore('ref', NEW.address->'postcode');
2230 IF NEW.class in ('boundary')
2231 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2232 DELETE FROM placex where place_id = existingplacex.place_id;
2238 address = NEW.address,
2239 parent_place_id = null,
2240 extratags = NEW.extratags,
2241 admin_level = NEW.admin_level,
2243 geometry = NEW.geometry
2244 where place_id = existingplacex.place_id;
2246 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2247 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2248 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2249 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2250 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);
2253 -- linked places should get potential new naming and addresses
2254 IF existingplacex.linked_place_id is not NULL THEN
2257 extratags = p.extratags,
2260 where x.place_id = existingplacex.linked_place_id
2261 and x.indexed_status = 0
2262 and x.osm_type = p.osm_type
2263 and x.osm_id = p.osm_id
2264 and x.class = p.class;
2269 -- Abort the add (we modified the existing place instead)
2274 $$ LANGUAGE plpgsql;
2277 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2282 IF name is null THEN
2286 FOR j IN 1..array_upper(languagepref,1) LOOP
2287 IF name ? languagepref[j] THEN
2288 result := trim(name->languagepref[j]);
2289 IF result != '' THEN
2295 -- anything will do as a fallback - just take the first name type thing there is
2296 RETURN trim((avals(name))[1]);
2299 LANGUAGE plpgsql IMMUTABLE;
2302 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2313 search := ARRAY['ref'];
2316 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2319 select rank_address,name,distance,length(name::text) as namelength
2320 from place_addressline join placex on (address_place_id = placex.place_id)
2321 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2322 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2324 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2325 FOR j IN 1..array_upper(search, 1) LOOP
2326 FOR k IN 1..array_upper(location.name, 1) LOOP
2327 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
2328 result[(100 - location.rank_address)] := trim(location.name[k].value);
2329 found := location.rank_address;
2336 RETURN array_to_string(result,', ');
2341 --housenumber only needed for tiger data
2342 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2354 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2355 currresult := trim(get_name_by_language(location.name, languagepref));
2356 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2357 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2358 prevresult := currresult;
2362 RETURN array_to_string(result,', ');
2367 DROP TYPE IF EXISTS addressline CASCADE;
2368 create type addressline as (
2375 admin_level INTEGER,
2378 rank_address INTEGER,
2382 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2385 for_place_id BIGINT;
2390 countrylocation RECORD;
2391 searchcountrycode varchar(2);
2392 searchhousenumber TEXT;
2393 searchhousename HSTORE;
2394 searchrankaddress INTEGER;
2395 searchpostcode TEXT;
2401 -- first query osmline (interpolation lines)
2402 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2403 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2404 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2405 IF for_place_id IS NOT NULL THEN
2406 searchhousenumber = in_housenumber::text;
2409 --then query tiger data
2410 -- %NOTIGERDATA% IF 0 THEN
2411 IF for_place_id IS NULL THEN
2412 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2413 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2414 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2415 IF for_place_id IS NOT NULL THEN
2416 searchhousenumber = in_housenumber::text;
2419 -- %NOTIGERDATA% END IF;
2421 -- %NOAUXDATA% IF 0 THEN
2422 IF for_place_id IS NULL THEN
2423 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2424 WHERE place_id = in_place_id
2425 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2427 -- %NOAUXDATA% END IF;
2429 IF for_place_id IS NULL THEN
2430 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2431 WHERE place_id = in_place_id and rank_search > 27
2432 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2435 IF for_place_id IS NULL THEN
2436 select coalesce(linked_place_id, place_id), country_code,
2437 housenumber, rank_search, postcode, null
2438 from placex where place_id = in_place_id
2439 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2442 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2445 hadcountry := false;
2447 select placex.place_id, osm_type, osm_id,
2448 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2449 class, type, admin_level, true as fromarea, true as isaddress,
2450 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2451 0 as distance, country_code, postcode
2453 where place_id = for_place_id
2455 --RAISE WARNING '%',location;
2456 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2457 searchcountrycode := location.country_code;
2459 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2460 location.isaddress := FALSE;
2462 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2463 searchpostcode := location.postcode;
2465 IF location.rank_address = 4 AND location.isaddress THEN
2468 IF location.rank_address < 4 AND NOT hadcountry THEN
2469 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2470 IF countryname IS NOT NULL THEN
2471 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2472 RETURN NEXT countrylocation;
2475 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2476 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2477 location.distance)::addressline;
2478 RETURN NEXT countrylocation;
2479 found := location.rank_address;
2483 select placex.place_id, osm_type, osm_id,
2484 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2485 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2486 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2487 admin_level, fromarea, isaddress,
2488 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,
2489 distance,country_code,postcode
2490 from place_addressline join placex on (address_place_id = placex.place_id)
2491 where place_addressline.place_id = for_place_id
2492 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2493 and address_place_id != for_place_id
2494 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2495 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2497 --RAISE WARNING '%',location;
2498 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2499 searchcountrycode := location.country_code;
2501 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2502 location.isaddress := FALSE;
2504 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL and location.postcode not similar to '%(,|;)%' THEN
2505 searchpostcode := location.postcode;
2507 IF location.rank_address = 4 AND location.isaddress THEN
2510 IF location.rank_address < 4 AND NOT hadcountry THEN
2511 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2512 IF countryname IS NOT NULL THEN
2513 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2514 RETURN NEXT countrylocation;
2517 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2518 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2519 location.distance)::addressline;
2520 RETURN NEXT countrylocation;
2521 found := location.rank_address;
2525 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2526 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2527 IF countryname IS NOT NULL THEN
2528 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2529 RETURN NEXT location;
2533 IF searchcountrycode IS NOT NULL THEN
2534 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2535 RETURN NEXT location;
2538 IF searchhousename IS NOT NULL THEN
2539 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2540 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2541 RETURN NEXT location;
2544 IF searchhousenumber IS NOT NULL THEN
2545 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2546 RETURN NEXT location;
2549 IF searchpostcode IS NOT NULL THEN
2550 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2551 RETURN NEXT location;
2560 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2566 ELSEIF rank < 4 THEN
2568 ELSEIF rank < 8 THEN
2570 ELSEIF rank < 12 THEN
2572 ELSEIF rank < 16 THEN
2574 ELSEIF rank = 16 THEN
2576 ELSEIF rank = 17 THEN
2577 RETURN 'Town / Island';
2578 ELSEIF rank = 18 THEN
2579 RETURN 'Village / Hamlet';
2580 ELSEIF rank = 20 THEN
2582 ELSEIF rank = 21 THEN
2583 RETURN 'Postcode Area';
2584 ELSEIF rank = 22 THEN
2585 RETURN 'Croft / Farm / Locality / Islet';
2586 ELSEIF rank = 23 THEN
2587 RETURN 'Postcode Area';
2588 ELSEIF rank = 25 THEN
2589 RETURN 'Postcode Point';
2590 ELSEIF rank = 26 THEN
2591 RETURN 'Street / Major Landmark';
2592 ELSEIF rank = 27 THEN
2593 RETURN 'Minory Street / Path';
2594 ELSEIF rank = 28 THEN
2595 RETURN 'House / Building';
2597 RETURN 'Other: '||rank;
2604 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2610 ELSEIF rank < 2 THEN
2612 ELSEIF rank < 4 THEN
2614 ELSEIF rank = 5 THEN
2616 ELSEIF rank < 8 THEN
2618 ELSEIF rank < 12 THEN
2620 ELSEIF rank < 16 THEN
2622 ELSEIF rank = 16 THEN
2624 ELSEIF rank = 17 THEN
2625 RETURN 'Town / Village / Hamlet';
2626 ELSEIF rank = 20 THEN
2628 ELSEIF rank = 21 THEN
2629 RETURN 'Postcode Area';
2630 ELSEIF rank = 22 THEN
2631 RETURN 'Croft / Farm / Locality / Islet';
2632 ELSEIF rank = 23 THEN
2633 RETURN 'Postcode Area';
2634 ELSEIF rank = 25 THEN
2635 RETURN 'Postcode Point';
2636 ELSEIF rank = 26 THEN
2637 RETURN 'Street / Major Landmark';
2638 ELSEIF rank = 27 THEN
2639 RETURN 'Minory Street / Path';
2640 ELSEIF rank = 28 THEN
2641 RETURN 'House / Building';
2643 RETURN 'Other: '||rank;
2650 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2651 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2656 place_centroid GEOMETRY;
2657 out_partition INTEGER;
2658 out_parent_place_id BIGINT;
2660 address_street_word_id INTEGER;
2665 place_centroid := ST_Centroid(pointgeo);
2666 out_partition := get_partition(in_countrycode);
2667 out_parent_place_id := null;
2669 address_street_word_id := get_name_id(make_standard_name(in_street));
2670 IF address_street_word_id IS NOT NULL THEN
2671 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2672 out_parent_place_id := location.place_id;
2676 IF out_parent_place_id IS NULL THEN
2677 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2678 out_parent_place_id := location.place_id;
2682 out_postcode := in_postcode;
2683 IF out_postcode IS NULL THEN
2684 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2686 IF out_postcode IS NULL THEN
2687 out_postcode := getNearestPostcode(out_partition, place_centroid);
2691 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2692 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2693 newpoints := newpoints + 1;
2700 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2707 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2708 IF members[i+1] = member THEN
2709 result := result || members[i];
2718 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2724 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2725 IF members[i+1] = ANY(memberLabels) THEN
2726 RETURN NEXT members[i];
2735 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2736 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2738 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2739 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
2740 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2741 ), '') AS bytea), 'UTF8');
2743 LANGUAGE SQL IMMUTABLE STRICT;
2745 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2749 RETURN decode_url_part(p);
2751 WHEN others THEN return null;
2754 LANGUAGE plpgsql IMMUTABLE;
2756 DROP TYPE wikipedia_article_match CASCADE;
2757 create type wikipedia_article_match as (
2763 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2769 wiki_article_title TEXT;
2770 wiki_article_language TEXT;
2771 result wikipedia_article_match;
2773 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'];
2775 WHILE langs[i] IS NOT NULL LOOP
2776 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2777 IF wiki_article is not null THEN
2778 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2779 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2780 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2781 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2782 wiki_article := replace(wiki_article,' ','_');
2783 IF strpos(wiki_article, ':') IN (3,4) THEN
2784 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2785 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2787 wiki_article_title := trim(wiki_article);
2788 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;
2791 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2792 from wikipedia_article
2793 where language = wiki_article_language and
2794 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2796 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2797 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2798 where wikipedia_redirect.language = wiki_article_language and
2799 (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'\\',''))
2800 order by importance desc limit 1 INTO result;
2802 IF result.language is not null THEN
2813 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2814 RETURNS SETOF GEOMETRY
2828 remainingdepth INTEGER;
2833 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2835 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2836 RETURN NEXT geometry;
2840 remainingdepth := maxdepth - 1;
2841 area := ST_AREA(geometry);
2842 IF remainingdepth < 1 OR area < maxarea THEN
2843 RETURN NEXT geometry;
2847 xmin := st_xmin(geometry);
2848 xmax := st_xmax(geometry);
2849 ymin := st_ymin(geometry);
2850 ymax := st_ymax(geometry);
2851 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2853 -- if the geometry completely covers the box don't bother to slice any more
2854 IF ST_AREA(secbox) = area THEN
2855 RETURN NEXT geometry;
2859 xmid := (xmin+xmax)/2;
2860 ymid := (ymin+ymax)/2;
2863 FOR seg IN 1..4 LOOP
2866 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2869 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2872 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2875 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2878 IF st_intersects(geometry, secbox) THEN
2879 secgeo := st_intersection(geometry, secbox);
2880 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2881 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2882 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2884 RETURN NEXT geo.geom;
2896 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2897 RETURNS SETOF GEOMETRY
2902 -- 10000000000 is ~~ 1x1 degree
2903 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2904 RETURN NEXT geo.geom;
2912 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2916 osmtype character(1);
2920 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2921 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2922 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2923 -- force delete from place/placex by making it a very small geometry
2924 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;
2925 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2932 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2940 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2941 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2942 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2943 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2944 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2945 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2946 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'));
2947 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2948 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'));
2954 ELSEIF rank < 18 THEN
2956 ELSEIF rank < 20 THEN
2958 ELSEIF rank = 21 THEN
2960 ELSEIF rank < 24 THEN
2962 ELSEIF rank < 26 THEN
2963 diameter := 0.002; -- 100 to 200 meters
2964 ELSEIF rank < 28 THEN
2965 diameter := 0.001; -- 50 to 100 meters
2967 IF diameter > 0 THEN
2969 -- roads may cause reparenting for >27 rank places
2970 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2971 ELSEIF rank >= 16 THEN
2972 -- up to rank 16, street-less addresses may need reparenting
2973 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');
2975 -- for all other places the search terms may change as well
2976 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);