1 -- Splits the line at the given point and returns the two parts
2 -- in a multilinestring.
3 CREATE OR REPLACE FUNCTION split_line_on_node(line GEOMETRY, point GEOMETRY)
7 RETURN ST_Split(ST_Snap(line, point, 0.0005), point);
13 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
18 -- RAISE WARNING '%',place;
19 NEWgeometry := ST_PointOnSurface(place);
20 RETURN (partition*1000000) + (500-ST_X(NEWgeometry)::integer)*1000 + (500-ST_Y(NEWgeometry)::integer);
23 LANGUAGE plpgsql IMMUTABLE;
25 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
26 AS '{modulepath}/nominatim.so', 'transliteration'
27 LANGUAGE c IMMUTABLE STRICT;
29 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
30 AS '{modulepath}/nominatim.so', 'gettokenstring'
31 LANGUAGE c IMMUTABLE STRICT;
33 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
38 o := gettokenstring(transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
91 return_word_id INTEGER;
93 lookup_token := ' '||trim(lookup_word);
94 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
95 IF return_word_id IS NULL THEN
96 return_word_id := nextval('seq_word');
97 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
99 RETURN return_word_id;
104 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
109 return_word_id INTEGER;
111 lookup_token := ' '||trim(lookup_word);
112 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
113 IF return_word_id IS NULL THEN
114 return_word_id := nextval('seq_word');
115 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
117 RETURN return_word_id;
122 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
127 return_word_id INTEGER;
129 lookup_token := ' '||trim(lookup_word);
130 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
131 IF return_word_id IS NULL THEN
132 return_word_id := nextval('seq_word');
133 INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
135 RETURN return_word_id;
140 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
145 nospace_lookup_token TEXT;
146 return_word_id INTEGER;
148 lookup_token := ' '||trim(lookup_word);
149 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
150 IF return_word_id IS NULL THEN
151 return_word_id := nextval('seq_word');
152 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
153 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
154 -- IF ' '||nospace_lookup_token != lookup_token THEN
155 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
158 RETURN return_word_id;
163 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
168 RETURN getorcreate_name_id(lookup_word, '');
173 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
178 return_word_id INTEGER;
180 lookup_token := trim(lookup_word);
181 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
182 RETURN return_word_id;
185 LANGUAGE plpgsql IMMUTABLE;
187 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
192 return_word_id INTEGER;
194 lookup_token := ' '||trim(lookup_word);
195 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
196 RETURN return_word_id;
199 LANGUAGE plpgsql IMMUTABLE;
201 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
206 return_word_ids INTEGER[];
208 lookup_token := ' '||trim(lookup_word);
209 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
210 RETURN return_word_ids;
213 LANGUAGE plpgsql IMMUTABLE;
215 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
222 IF array_upper(a, 1) IS NULL THEN
225 IF array_upper(b, 1) IS NULL THEN
229 FOR i IN 1..array_upper(b, 1) LOOP
230 IF NOT (ARRAY[b[i]] <@ r) THEN
237 LANGUAGE plpgsql IMMUTABLE;
239 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
248 FOR item IN SELECT (each(src)).* LOOP
250 s := make_standard_name(item.value);
251 w := getorcreate_country(s, lookup_country_code);
253 words := regexp_split_to_array(item.value, E'[,;()]');
254 IF array_upper(words, 1) != 1 THEN
255 FOR j IN 1..array_upper(words, 1) LOOP
256 s := make_standard_name(words[j]);
258 w := getorcreate_country(s, lookup_country_code);
267 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
277 result := '{}'::INTEGER[];
279 FOR item IN SELECT (each(src)).* LOOP
281 s := make_standard_name(item.value);
283 w := getorcreate_name_id(s, item.value);
285 IF not(ARRAY[w] <@ result) THEN
286 result := result || w;
289 w := getorcreate_word_id(s);
291 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
292 result := result || w;
295 words := string_to_array(s, ' ');
296 IF array_upper(words, 1) IS NOT NULL THEN
297 FOR j IN 1..array_upper(words, 1) LOOP
298 IF (words[j] != '') THEN
299 w = getorcreate_word_id(words[j]);
300 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
301 result := result || w;
307 words := regexp_split_to_array(item.value, E'[,;()]');
308 IF array_upper(words, 1) != 1 THEN
309 FOR j IN 1..array_upper(words, 1) LOOP
310 s := make_standard_name(words[j]);
312 w := getorcreate_word_id(s);
313 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
314 result := result || w;
320 s := regexp_replace(item.value, '市$', '');
321 IF s != item.value THEN
322 s := make_standard_name(s);
324 w := getorcreate_name_id(s, item.value);
325 IF NOT (ARRAY[w] <@ result) THEN
326 result := result || w;
336 LANGUAGE plpgsql IMMUTABLE;
338 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
348 result := '{}'::INTEGER[];
350 s := make_standard_name(src);
351 w := getorcreate_name_id(s, src);
353 IF NOT (ARRAY[w] <@ result) THEN
354 result := result || w;
357 w := getorcreate_word_id(s);
359 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
360 result := result || w;
363 words := string_to_array(s, ' ');
364 IF array_upper(words, 1) IS NOT NULL THEN
365 FOR j IN 1..array_upper(words, 1) LOOP
366 IF (words[j] != '') THEN
367 w = getorcreate_word_id(words[j]);
368 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
369 result := result || w;
375 words := regexp_split_to_array(src, E'[,;()]');
376 IF array_upper(words, 1) != 1 THEN
377 FOR j IN 1..array_upper(words, 1) LOOP
378 s := make_standard_name(words[j]);
380 w := getorcreate_word_id(s);
381 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
382 result := result || w;
388 s := regexp_replace(src, '市$', '');
390 s := make_standard_name(s);
392 w := getorcreate_name_id(s, src);
393 IF NOT (ARRAY[w] <@ result) THEN
394 result := result || w;
402 LANGUAGE plpgsql IMMUTABLE;
404 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
407 place_centre GEOMETRY;
410 place_centre := ST_PointOnSurface(place);
412 --DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
414 -- Try for a OSM polygon
415 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
417 RETURN nearcountry.country_code;
420 --DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
422 -- Try for OSM fallback data
423 -- The order is to deal with places like HongKong that are 'states' within another polygon
424 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
426 RETURN nearcountry.country_code;
429 --DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
431 -- Natural earth data
432 FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
434 RETURN nearcountry.country_code;
437 --DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
440 FOR nearcountry IN select country_code from country_osm_grid where st_dwithin(geometry, place_centre, 0.5) order by st_distance(geometry, place_centre) asc, area asc limit 1
442 RETURN nearcountry.country_code;
445 --DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
447 -- Natural earth data
448 FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
450 RETURN nearcountry.country_code;
456 LANGUAGE plpgsql IMMUTABLE;
458 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
463 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
465 RETURN lower(nearcountry.country_default_language_code);
470 LANGUAGE plpgsql IMMUTABLE;
472 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
477 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
479 RETURN lower(nearcountry.country_default_language_codes);
484 LANGUAGE plpgsql IMMUTABLE;
486 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
491 FOR nearcountry IN select partition from country_name where country_code = in_country_code
493 RETURN nearcountry.partition;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
504 DELETE FROM location_area where place_id = OLD_place_id;
505 -- TODO:location_area
511 CREATE OR REPLACE FUNCTION add_location(
513 country_code varchar(2),
517 rank_address INTEGER,
532 IF rank_search > 25 THEN
533 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
536 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
538 x := deleteLocationArea(partition, place_id, rank_search);
541 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
544 centroid := ST_Centroid(geometry);
546 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
547 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
553 IF rank_address = 0 THEN
555 ELSEIF rank_search <= 14 THEN
557 ELSEIF rank_search <= 15 THEN
559 ELSEIF rank_search <= 16 THEN
561 ELSEIF rank_search <= 17 THEN
563 ELSEIF rank_search <= 21 THEN
565 ELSEIF rank_search = 25 THEN
569 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
571 secgeo := ST_Buffer(geometry, diameter);
572 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
582 -- find the parent road of the cut road parts
583 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
584 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
589 parent_place_id BIGINT;
590 address_street_word_ids INTEGER[];
596 addr_street = street;
599 IF addr_street is null and addr_place is null THEN
600 select nodes from planet_osm_ways where id = wayid INTO waynodes;
601 FOR location IN SELECT placex.address from placex
602 where osm_type = 'N' and osm_id = ANY(waynodes)
603 and placex.address is not null
604 and (placex.address ? 'street' or placex.address ? 'place')
605 and indexed_status < 100
607 addr_street = location.address->'street';
608 addr_place = location.address->'place';
612 IF addr_street IS NOT NULL THEN
613 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
614 IF address_street_word_ids IS NOT NULL THEN
615 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
616 parent_place_id := location.place_id;
621 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
622 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
623 IF address_street_word_ids IS NOT NULL THEN
624 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
625 parent_place_id := location.place_id;
630 IF parent_place_id is null THEN
631 FOR location IN SELECT place_id FROM placex
632 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
633 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
634 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
635 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
637 parent_place_id := location.place_id;
641 IF parent_place_id is null THEN
645 RETURN parent_place_id;
651 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
654 NEW.place_id := nextval('seq_place');
655 NEW.indexed_date := now();
657 IF NEW.indexed_status IS NULL THEN
658 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
659 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
660 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
664 NEW.indexed_status := 1; --STATUS_NEW
665 NEW.country_code := lower(get_country_code(NEW.linegeo));
667 NEW.partition := get_partition(NEW.country_code);
668 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
677 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
683 country_code VARCHAR(2);
684 default_language VARCHAR(10);
689 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
691 NEW.place_id := nextval('seq_place');
692 NEW.indexed_status := 1; --STATUS_NEW
694 NEW.country_code := lower(get_country_code(NEW.geometry));
696 NEW.partition := get_partition(NEW.country_code);
697 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
699 -- copy 'name' to or from the default language (if there is a default language)
700 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
701 default_language := get_country_language_code(NEW.country_code);
702 IF default_language IS NOT NULL THEN
703 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
704 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
705 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
706 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
711 IF NEW.osm_type = 'X' THEN
712 -- E'X'ternal records should already be in the right format so do nothing
714 NEW.rank_search := 30;
715 NEW.rank_address := NEW.rank_search;
717 -- By doing in postgres we have the country available to us - currently only used for postcode
718 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
720 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
721 -- most likely just a part of a multipolygon postcode boundary, throw it away
725 NEW.postcode := NEW.address->'postcode';
726 NEW.name := hstore('ref', NEW.postcode);
728 IF NEW.country_code = 'gb' THEN
730 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
731 NEW.rank_search := 25;
732 NEW.rank_address := 5;
733 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
734 NEW.rank_search := 23;
735 NEW.rank_address := 5;
736 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
737 NEW.rank_search := 21;
738 NEW.rank_address := 5;
741 ELSEIF NEW.country_code = 'sg' THEN
743 IF NEW.postcode ~ '^([0-9]{6})$' THEN
744 NEW.rank_search := 25;
745 NEW.rank_address := 11;
748 ELSEIF NEW.country_code = 'de' THEN
750 IF NEW.postcode ~ '^([0-9]{5})$' THEN
751 NEW.rank_search := 21;
752 NEW.rank_address := 11;
756 -- Guess at the postcode format and coverage (!)
757 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
758 NEW.rank_search := 21;
759 NEW.rank_address := 11;
761 -- Does it look splitable into and area and local code?
762 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
764 IF postcode IS NOT NULL THEN
765 NEW.rank_search := 25;
766 NEW.rank_address := 11;
767 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
768 NEW.rank_search := 21;
769 NEW.rank_address := 11;
774 ELSEIF NEW.class = 'place' THEN
775 IF NEW.type in ('continent') THEN
776 NEW.rank_search := 2;
777 NEW.rank_address := NEW.rank_search;
778 NEW.country_code := NULL;
779 ELSEIF NEW.type in ('sea') THEN
780 NEW.rank_search := 2;
781 NEW.rank_address := 0;
782 NEW.country_code := NULL;
783 ELSEIF NEW.type in ('country') THEN
784 NEW.rank_search := 4;
785 NEW.rank_address := NEW.rank_search;
786 ELSEIF NEW.type in ('state') THEN
787 NEW.rank_search := 8;
788 NEW.rank_address := NEW.rank_search;
789 ELSEIF NEW.type in ('region') THEN
790 NEW.rank_search := 18; -- dropped from previous value of 10
791 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
792 ELSEIF NEW.type in ('county') THEN
793 NEW.rank_search := 12;
794 NEW.rank_address := NEW.rank_search;
795 ELSEIF NEW.type in ('city') THEN
796 NEW.rank_search := 16;
797 NEW.rank_address := NEW.rank_search;
798 ELSEIF NEW.type in ('island') THEN
799 NEW.rank_search := 17;
800 NEW.rank_address := 0;
801 ELSEIF NEW.type in ('town') THEN
802 NEW.rank_search := 18;
803 NEW.rank_address := 16;
804 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
805 NEW.rank_search := 19;
806 NEW.rank_address := 16;
807 ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
808 NEW.rank_search := 20;
809 NEW.rank_address := NEW.rank_search;
810 ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
811 NEW.rank_search := 20;
812 NEW.rank_address := 0;
813 -- Irish townlands, tagged as place=locality and locality=townland
814 IF (NEW.extratags -> 'locality') = 'townland' THEN
815 NEW.rank_address := 20;
817 ELSEIF NEW.type in ('neighbourhood') THEN
818 NEW.rank_search := 22;
819 NEW.rank_address := 22;
820 ELSEIF NEW.type in ('house','building') THEN
821 NEW.rank_search := 30;
822 NEW.rank_address := NEW.rank_search;
823 ELSEIF NEW.type in ('houses') THEN
824 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
825 NEW.rank_search := 28;
826 NEW.rank_address := 0;
829 ELSEIF NEW.class = 'boundary' THEN
830 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
831 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
834 NEW.rank_search := NEW.admin_level * 2;
835 IF NEW.type = 'administrative' THEN
836 NEW.rank_address := NEW.rank_search;
838 NEW.rank_address := 0;
840 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
841 NEW.rank_search := 22;
842 IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
843 NEW.rank_address := NEW.rank_search;
845 NEW.rank_address := 0;
847 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
848 NEW.rank_search := 18;
849 NEW.rank_address := 0;
850 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
851 NEW.rank_search := 4;
852 NEW.rank_address := NEW.rank_search;
853 -- any feature more than 5 square miles is probably worth indexing
854 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
855 NEW.rank_search := 22;
856 NEW.rank_address := 0;
857 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
859 ELSEIF NEW.class = 'waterway' THEN
860 IF NEW.osm_type = 'R' THEN
861 NEW.rank_search := 16;
863 NEW.rank_search := 17;
865 NEW.rank_address := 0;
866 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
867 NEW.rank_search := 27;
868 NEW.rank_address := NEW.rank_search;
869 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
870 NEW.rank_search := 26;
871 NEW.rank_address := NEW.rank_search;
872 ELSEIF NEW.class = 'mountain_pass' THEN
873 NEW.rank_search := 20;
874 NEW.rank_address := 0;
879 IF NEW.rank_search > 30 THEN
880 NEW.rank_search := 30;
883 IF NEW.rank_address > 30 THEN
884 NEW.rank_address := 30;
887 IF (NEW.extratags -> 'capital') = 'yes' THEN
888 NEW.rank_search := NEW.rank_search - 1;
891 -- a country code make no sense below rank 4 (country)
892 IF NEW.rank_search < 4 THEN
893 NEW.country_code := NULL;
896 -- Block import below rank 22
897 -- IF NEW.rank_search > 22 THEN
901 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
903 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
905 IF NEW.rank_address > 0 THEN
906 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
907 -- Performance: We just can't handle re-indexing for country level changes
908 IF st_area(NEW.geometry) < 1 THEN
909 -- mark items within the geometry for re-indexing
910 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
912 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
913 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
914 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
915 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
916 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and addr_place is not null));
919 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
921 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
922 IF NEW.type='postcode' THEN
924 ELSEIF NEW.rank_search < 16 THEN
926 ELSEIF NEW.rank_search < 18 THEN
928 ELSEIF NEW.rank_search < 20 THEN
930 ELSEIF NEW.rank_search = 21 THEN
932 ELSEIF NEW.rank_search < 24 THEN
934 ELSEIF NEW.rank_search < 26 THEN
935 diameter := 0.002; -- 100 to 200 meters
936 ELSEIF NEW.rank_search < 28 THEN
937 diameter := 0.001; -- 50 to 100 meters
940 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
941 IF NEW.rank_search >= 26 THEN
942 -- roads may cause reparenting for >27 rank places
943 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
944 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
945 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
946 ELSEIF NEW.rank_search >= 16 THEN
947 -- up to rank 16, street-less addresses may need reparenting
948 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
950 -- for all other places the search terms may change as well
951 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);
958 -- add to tables for special search
959 -- Note: won't work on initial import because the classtype tables
960 -- do not yet exist. It won't hurt either.
961 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
962 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
964 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
965 USING NEW.place_id, ST_Centroid(NEW.geometry);
974 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
978 place_centroid GEOMETRY;
992 IF OLD.indexed_status = 100 THEN
993 delete from location_property_osmline where place_id = OLD.place_id;
997 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1001 NEW.interpolationtype = NEW.address->'interpolation';
1003 place_centroid := ST_PointOnSurface(NEW.linegeo);
1004 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1005 NEW.address->'place',
1006 NEW.partition, place_centroid, NEW.linegeo);
1009 IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
1010 NEW.postcode = NEW.address->'postcode';
1013 -- if the line was newly inserted, split the line as necessary
1014 IF OLD.indexed_status = 1 THEN
1015 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1017 IF array_upper(waynodes, 1) IS NULL THEN
1021 linegeo := NEW.linegeo;
1022 startnumber := NULL;
1023 postcode := NEW.postcode;
1025 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1027 select osm_id, address, geometry
1028 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1029 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1030 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1031 IF nextnode.osm_id IS NOT NULL THEN
1032 --RAISE NOTICE 'place_id is not null';
1033 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1034 -- Make sure that the point is actually on the line. That might
1035 -- be a bit paranoid but ensures that the algorithm still works
1036 -- should osm2pgsql attempt to repair geometries.
1037 splitline := split_line_on_node(linegeo, nextnode.geometry);
1038 sectiongeo := ST_GeometryN(splitline, 1);
1039 linegeo := ST_GeometryN(splitline, 2);
1041 sectiongeo = linegeo;
1043 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1045 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1046 AND startnumber != endnumber
1047 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1049 IF (startnumber > endnumber) THEN
1050 housenum := endnumber;
1051 endnumber := startnumber;
1052 startnumber := housenum;
1053 sectiongeo := ST_Reverse(sectiongeo);
1056 seg_postcode := coalesce(postcode,
1057 prevnode.address->'postcode',
1058 nextnode.address->'postcode');
1060 IF NEW.startnumber IS NULL THEN
1061 NEW.startnumber := startnumber;
1062 NEW.endnumber := endnumber;
1063 NEW.linegeo := sectiongeo;
1064 NEW.postcode := seg_postcode;
1066 insert into location_property_osmline
1067 (linegeo, partition, osm_id, parent_place_id,
1068 startnumber, endnumber, interpolationtype,
1069 address, postcode, country_code,
1070 geometry_sector, indexed_status)
1071 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1072 startnumber, endnumber, NEW.interpolationtype,
1073 NEW.address, seg_postcode,
1074 NEW.country_code, NEW.geometry_sector, 0);
1078 -- early break if we are out of line string,
1079 -- might happen when a line string loops back on itself
1080 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1084 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1085 prevnode := nextnode;
1090 -- marking descendants for reparenting is not needed, because there are
1091 -- actually no descendants for interpolation lines
1099 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1104 place_centroid GEOMETRY;
1106 search_maxdistance FLOAT[];
1107 search_mindistance FLOAT[];
1108 address_havelevel BOOLEAN[];
1115 relation_members TEXT[];
1117 linkedplacex RECORD;
1118 search_diameter FLOAT;
1119 search_prevdiameter FLOAT;
1120 search_maxrank INTEGER;
1121 address_maxrank INTEGER;
1122 address_street_word_id INTEGER;
1123 address_street_word_ids INTEGER[];
1124 parent_place_id_rank BIGINT;
1129 location_rank_search INTEGER;
1130 location_distance FLOAT;
1131 location_parent GEOMETRY;
1132 location_isaddress BOOLEAN;
1133 location_keywords INTEGER[];
1135 default_language TEXT;
1136 name_vector INTEGER[];
1137 nameaddress_vector INTEGER[];
1139 linked_node_id BIGINT;
1144 IF OLD.indexed_status = 100 THEN
1145 --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
1146 delete from placex where place_id = OLD.place_id;
1150 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1154 --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
1156 --RAISE WARNING '%',NEW.place_id;
1157 --RAISE WARNING '%', NEW;
1159 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1160 -- Silently do nothing
1164 NEW.indexed_date = now();
1166 result := deleteSearchName(NEW.partition, NEW.place_id);
1167 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1168 result := deleteRoad(NEW.partition, NEW.place_id);
1169 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1170 UPDATE placex set linked_place_id = null, indexed_status = 2
1171 where linked_place_id = NEW.place_id;
1172 -- update not necessary for osmline, cause linked_place_id does not exist
1174 IF NEW.linked_place_id is not null THEN
1178 IF NEW.address is not NULL THEN
1179 IF NEW.address ? 'conscriptionnumber' THEN
1180 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1181 IF NEW.address ? 'streetnumber' THEN
1182 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1183 NEW.housenumber := NEW.address->'conscriptionnumber' || '/' || NEW.address->'streetnumber';
1185 NEW.housenumber := NEW.address->'conscriptionnumber';
1187 ELSEIF NEW.address ? 'streetnumber' THEN
1188 NEW.housenumber := NEW.address->'streetnumber';
1189 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1190 ELSEIF NEW.address ? 'housenumber' THEN
1191 NEW.housenumber := NEW.address->'housenumber';
1192 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1195 NEW.street = NEW.address->'street';
1196 NEW.addr_place = NEW.address->'place';
1197 NEW.postcode = NEW.address->'postcode';
1200 -- Speed up searches - just use the centroid of the feature
1201 -- cheaper but less acurate
1202 place_centroid := ST_PointOnSurface(NEW.geometry);
1203 NEW.centroid := null;
1205 -- recalculate country and partition
1206 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1207 -- for countries, believe the mapped country code,
1208 -- so that we remain in the right partition if the boundaries
1210 NEW.country_code := lower(NEW.address->'country');
1211 NEW.partition := get_partition(lower(NEW.country_code));
1212 IF NEW.partition = 0 THEN
1213 NEW.country_code := lower(get_country_code(place_centroid));
1214 NEW.partition := get_partition(NEW.country_code);
1217 IF NEW.rank_search >= 4 THEN
1218 NEW.country_code := lower(get_country_code(place_centroid));
1220 NEW.country_code := NULL;
1222 NEW.partition := get_partition(NEW.country_code);
1225 -- waterway ways are linked when they are part of a relation and have the same class/type
1226 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1227 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1229 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1230 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1231 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
1232 FOR linked_node_id IN SELECT place_id FROM placex
1233 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1234 and class = NEW.class and type = NEW.type
1235 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1237 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1244 -- Adding ourselves to the list simplifies address calculations later
1245 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1247 -- What level are we searching from
1248 search_maxrank := NEW.rank_search;
1250 -- Thought this wasn't needed but when we add new languages to the country_name table
1251 -- we need to update the existing names
1252 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1253 default_language := get_country_language_code(NEW.country_code);
1254 IF default_language IS NOT NULL THEN
1255 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1256 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1257 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1258 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1263 -- Initialise the name vector using our name
1264 name_vector := make_keywords(NEW.name);
1265 nameaddress_vector := '{}'::int[];
1268 address_havelevel[i] := false;
1271 NEW.importance := null;
1272 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1273 IF NEW.importance IS NULL THEN
1274 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;
1277 --RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
1279 -- ---------------------------------------------------------------------------
1280 -- For low level elements we inherit from our parent road
1281 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1283 --RAISE WARNING 'finding street for %', NEW;
1285 -- We won't get a better centroid, besides these places are too small to care
1286 NEW.centroid := place_centroid;
1288 NEW.parent_place_id := null;
1290 -- if we have a POI and there is no address information,
1291 -- see if we can get it from a surrounding building
1292 IF NEW.osm_type = 'N' AND NEW.street IS NULL AND NEW.addr_place IS NULL
1293 AND NEW.housenumber IS NULL THEN
1294 FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
1295 and address is not null
1296 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1297 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1300 NEW.housenumber := location.address->'housenumber';
1301 NEW.street := location.address->'street';
1302 NEW.addr_place := location.address->'place';
1306 -- We have to find our parent road.
1307 -- Copy data from linked items (points on ways, addr:street links, relations)
1309 -- Is this object part of a relation?
1310 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1312 -- At the moment we only process one type of relation - associatedStreet
1313 IF relation.tags @> ARRAY['associatedStreet'] THEN
1314 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1315 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1316 --RAISE WARNING 'node in relation %',relation;
1317 SELECT place_id from placex where osm_type = 'W'
1318 and osm_id = substring(relation.members[i],2,200)::bigint
1319 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1326 -- Note that addr:street links can only be indexed once the street itself is indexed
1327 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1328 address_street_word_ids := get_name_ids(make_standard_name(NEW.street));
1329 IF address_street_word_ids IS NOT NULL THEN
1330 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1331 NEW.parent_place_id := location.place_id;
1336 IF NEW.parent_place_id IS NULL AND NEW.addr_place IS NOT NULL THEN
1337 address_street_word_ids := get_name_ids(make_standard_name(NEW.addr_place));
1338 IF address_street_word_ids IS NOT NULL THEN
1339 FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1340 NEW.parent_place_id := location.place_id;
1345 -- Is this node part of an interpolation?
1346 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1348 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1349 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1352 NEW.parent_place_id := location.parent_place_id;
1356 -- Is this node part of a way?
1357 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1359 FOR location IN select p.place_id, p.osm_id, p.parent_place_id, p.rank_search, p.street, p.addr_place from placex p, planet_osm_ways w
1360 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)
1363 -- Way IS a road then we are on it - that must be our road
1364 IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
1365 --RAISE WARNING 'node in way that is a street %',location;
1366 NEW.parent_place_id := location.place_id;
1369 -- If the way mentions a street or place address, try that for parenting.
1370 IF NEW.parent_place_id IS NULL AND location.street IS NOT NULL THEN
1371 address_street_word_ids := get_name_ids(make_standard_name(location.street));
1372 IF address_street_word_ids IS NOT NULL THEN
1373 FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1374 NEW.parent_place_id := linkedplacex.place_id;
1379 IF NEW.parent_place_id IS NULL AND location.addr_place IS NOT NULL THEN
1380 address_street_word_ids := get_name_ids(make_standard_name(location.addr_place));
1381 IF address_street_word_ids IS NOT NULL THEN
1382 FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
1383 NEW.parent_place_id := linkedplacex.place_id;
1388 -- Is the WAY part of a relation
1389 IF NEW.parent_place_id IS NULL THEN
1390 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1392 -- At the moment we only process one type of relation - associatedStreet
1393 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1394 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1395 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1396 --RAISE WARNING 'node in way that is in a relation %',relation;
1397 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1398 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1409 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1410 -- Still nothing, just use the nearest road
1411 IF NEW.parent_place_id IS NULL THEN
1412 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1413 NEW.parent_place_id := location.place_id;
1418 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1420 -- If we didn't find any road fallback to standard method
1421 IF NEW.parent_place_id IS NOT NULL THEN
1423 -- Get the details of the parent road
1424 select * from search_name where place_id = NEW.parent_place_id INTO location;
1425 NEW.country_code := location.country_code;
1427 -- Merge the postcode into the parent's address if necessary
1428 IF NEW.postcode IS NOT NULL THEN
1429 isin_tokens := '{}'::int[];
1430 address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
1431 IF address_street_word_id is not null
1432 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1433 isin_tokens := isin_tokens || address_street_word_id;
1435 address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
1436 IF address_street_word_id is not null
1437 and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
1438 isin_tokens := isin_tokens || address_street_word_id;
1440 IF isin_tokens != '{}'::int[] THEN
1442 SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
1443 WHERE place_id = NEW.parent_place_id;
1447 --RAISE WARNING '%', NEW.name;
1448 -- If there is no name it isn't searchable, don't bother to create a search record
1449 IF NEW.name is NULL THEN
1453 -- Merge address from parent
1454 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1455 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1457 -- Performance, it would be more acurate to do all the rest of the import
1458 -- process but it takes too long
1459 -- Just be happy with inheriting from parent road only
1461 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1462 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1465 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);
1472 -- RAISE WARNING ' INDEXING Started:';
1473 -- RAISE WARNING ' INDEXING: %',NEW;
1475 -- ---------------------------------------------------------------------------
1478 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1480 -- see if we have any special relation members
1481 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1483 -- RAISE WARNING 'get_osm_rel_members, label';
1484 IF relation_members IS NOT NULL THEN
1485 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1487 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1488 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1490 -- If we don't already have one use this as the centre point of the geometry
1491 IF NEW.centroid IS NULL THEN
1492 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1495 -- merge in the label name, re-init word vector
1496 IF NOT linkedPlacex.name IS NULL THEN
1497 NEW.name := linkedPlacex.name || NEW.name;
1498 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1501 -- merge in extra tags
1502 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1504 -- mark the linked place (excludes from search results)
1505 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1507 -- keep a note of the node id in case we need it for wikipedia in a bit
1508 linked_node_id := linkedPlacex.osm_id;
1513 IF NEW.centroid IS NULL THEN
1515 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1517 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1518 and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
1520 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1521 -- But that can be fixed by explicitly setting the label in the data
1522 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1523 AND NEW.rank_address = linkedPlacex.rank_address THEN
1525 -- If we don't already have one use this as the centre point of the geometry
1526 IF NEW.centroid IS NULL THEN
1527 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1530 -- merge in the name, re-init word vector
1531 IF NOT linkedPlacex.name IS NULL THEN
1532 NEW.name := linkedPlacex.name || NEW.name;
1533 name_vector := make_keywords(NEW.name);
1536 -- merge in extra tags
1537 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1539 -- mark the linked place (excludes from search results)
1540 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1542 -- keep a note of the node id in case we need it for wikipedia in a bit
1543 linked_node_id := linkedPlacex.osm_id;
1555 -- Name searches can be done for ways as well as relations
1556 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1558 -- not found one yet? how about doing a name search
1559 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1561 FOR linkedPlacex IN select placex.* from placex WHERE
1562 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1563 AND placex.rank_address = NEW.rank_address
1564 AND placex.place_id != NEW.place_id
1565 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1566 AND st_covers(NEW.geometry, placex.geometry)
1569 -- If we don't already have one use this as the centre point of the geometry
1570 IF NEW.centroid IS NULL THEN
1571 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1574 -- merge in the name, re-init word vector
1575 NEW.name := linkedPlacex.name || NEW.name;
1576 name_vector := make_keywords(NEW.name);
1578 -- merge in extra tags
1579 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1581 -- mark the linked place (excludes from search results)
1582 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1584 -- keep a note of the node id in case we need it for wikipedia in a bit
1585 linked_node_id := linkedPlacex.osm_id;
1589 IF NEW.centroid IS NOT NULL THEN
1590 place_centroid := NEW.centroid;
1591 -- Place might have had only a name tag before but has now received translations
1592 -- from the linked place. Make sure a name tag for the default language exists in
1594 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1595 default_language := get_country_language_code(NEW.country_code);
1596 IF default_language IS NOT NULL THEN
1597 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1598 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1599 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1600 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1606 -- Did we gain a wikipedia tag in the process? then we need to recalculate our importance
1607 IF NEW.importance is null THEN
1608 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1610 -- Still null? how about looking it up by the node id
1611 IF NEW.importance IS NULL THEN
1612 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;
1617 -- make sure all names are in the word table
1618 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
1619 perform create_country(NEW.name, lower(NEW.country_code));
1622 NEW.parent_place_id = 0;
1623 parent_place_id_rank = 0;
1626 -- convert isin to array of tokenids
1627 isin_tokens := '{}'::int[];
1628 IF NEW.address IS NOT NULL THEN
1629 isin := avals(NEW.address);
1630 IF array_upper(isin, 1) IS NOT NULL THEN
1631 FOR i IN 1..array_upper(isin, 1) LOOP
1632 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1633 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1634 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1635 isin_tokens := isin_tokens || address_street_word_id;
1638 -- merge word into address vector
1639 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1640 IF address_street_word_id IS NOT NULL THEN
1641 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1646 IF NEW.postcode IS NOT NULL THEN
1647 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1648 IF array_upper(isin, 1) IS NOT NULL THEN
1649 FOR i IN 1..array_upper(isin, 1) LOOP
1650 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1651 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1652 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1653 isin_tokens := isin_tokens || address_street_word_id;
1656 -- merge into address vector
1657 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1658 IF address_street_word_id IS NOT NULL THEN
1659 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1665 -- %NOTIGERDATA% IF 0 THEN
1666 -- for the USA we have an additional address table. Merge in zip codes from there too
1667 IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
1668 FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
1669 address_street_word_id := get_name_id(make_standard_name(location.postcode));
1670 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1671 isin_tokens := isin_tokens || address_street_word_id;
1673 -- also merge in the single word version
1674 address_street_word_id := get_word_id(make_standard_name(location.postcode));
1675 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1678 -- %NOTIGERDATA% END IF;
1680 -- RAISE WARNING 'ISIN: %', isin_tokens;
1682 -- Process area matches
1683 location_rank_search := 0;
1684 location_distance := 0;
1685 location_parent := NULL;
1686 -- added ourself as address already
1687 address_havelevel[NEW.rank_address] := true;
1688 -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1690 SELECT * from getNearFeatures(NEW.partition,
1691 CASE WHEN NEW.rank_search >= 26 THEN NEW.geometry
1692 ELSE place_centroid END,
1693 search_maxrank, isin_tokens)
1696 --RAISE WARNING ' AREA: %',location;
1698 IF location.rank_address != location_rank_search THEN
1699 location_rank_search := location.rank_address;
1700 IF location.isguess THEN
1701 location_distance := location.distance * 1.5;
1703 IF location.rank_address <= 12 THEN
1704 -- for county and above, if we have an area consider that exact
1705 -- (It would be nice to relax the constraint for places close to
1706 -- the boundary but we'd need the exact geometry for that. Too
1708 location_distance = 0;
1710 -- Below county level remain slightly fuzzy.
1711 location_distance := location.distance * 0.5;
1715 CONTINUE WHEN location.keywords <@ location_keywords;
1718 IF location.distance < location_distance OR NOT location.isguess THEN
1719 location_keywords := location.keywords;
1721 location_isaddress := NOT address_havelevel[location.rank_address];
1722 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1723 location_isaddress := ST_Contains(location_parent,location.centroid);
1726 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1727 -- Add it to the list of search terms
1728 IF location.rank_search > 4 THEN
1729 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1731 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1733 IF location_isaddress THEN
1735 address_havelevel[location.rank_address] := true;
1736 IF NOT location.isguess THEN
1737 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1740 IF location.rank_address > parent_place_id_rank THEN
1741 NEW.parent_place_id = location.place_id;
1742 parent_place_id_rank = location.rank_address;
1747 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1753 -- try using the isin value to find parent places
1754 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1755 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1756 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1757 IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
1759 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1761 --RAISE WARNING ' ISIN: %',location;
1763 IF location.rank_search > 4 THEN
1764 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1765 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1766 address_havelevel[location.rank_address] := true;
1768 IF location.rank_address > parent_place_id_rank THEN
1769 NEW.parent_place_id = location.place_id;
1770 parent_place_id_rank = location.rank_address;
1780 -- for long ways we should add search terms for the entire length
1781 IF st_length(NEW.geometry) > 0.05 THEN
1783 location_rank_search := 0;
1784 location_distance := 0;
1786 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1788 IF location.rank_address != location_rank_search THEN
1789 location_rank_search := location.rank_address;
1790 location_distance := location.distance * 1.5;
1793 IF location.rank_search > 4 AND location.distance < location_distance THEN
1795 -- Add it to the list of search terms
1796 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1797 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1805 -- if we have a name add this to the name search table
1806 IF NEW.name IS NOT NULL THEN
1808 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1809 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1812 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1813 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1816 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);
1820 -- If we've not managed to pick up a better one - default centroid
1821 IF NEW.centroid IS NULL THEN
1822 NEW.centroid := place_centroid;
1830 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1836 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1838 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1839 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1840 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1841 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1843 IF OLD.rank_address < 30 THEN
1845 -- mark everything linked to this place for re-indexing
1846 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1847 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1848 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1850 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1851 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1853 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1854 b := deleteRoad(OLD.partition, OLD.place_id);
1856 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1857 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1858 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1859 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1860 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1864 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1866 IF OLD.rank_address < 26 THEN
1867 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1870 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1872 IF OLD.name is not null THEN
1873 b := deleteSearchName(OLD.partition, OLD.place_id);
1876 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1878 DELETE FROM place_addressline where place_id = OLD.place_id;
1880 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1882 -- remove from tables for special search
1883 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1884 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1886 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1889 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1897 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1903 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1905 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1906 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1907 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;
1909 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1915 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;
1917 -- interpolations are special
1918 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1919 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1928 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1933 existingplacex RECORD;
1934 existingline RECORD;
1935 existinggeometry GEOMETRY;
1936 existingplace_id BIGINT;
1941 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1942 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1943 -- filter wrong tupels
1944 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
1945 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type,
1946 NEW.name, NEW.address->'country',
1947 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1948 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1952 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
1953 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
1954 -- Have we already done this place?
1955 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;
1957 -- Get the existing place_id
1958 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
1960 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
1961 IF existing.osm_type IS NULL THEN
1962 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
1965 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1966 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1968 -- 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)
1969 IF existingline.osm_id IS NOT NULL THEN
1970 delete from location_property_osmline where osm_id = NEW.osm_id;
1973 -- for interpolations invalidate all nodes on the line
1974 update placex p set indexed_status = 2
1975 from planet_osm_ways w
1976 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
1979 INSERT INTO location_property_osmline (osm_id, address, linegeo)
1980 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
1983 IF existing.osm_type IS NULL THEN
1987 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
1988 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
1989 OR existing.geometry::text != NEW.geometry::text
1994 address = NEW.address,
1995 extratags = NEW.extratags,
1996 admin_level = NEW.admin_level,
1997 geometry = NEW.geometry
1998 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2003 ELSE -- insert to placex
2005 -- Patch in additional country names
2006 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2007 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2008 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2009 IF existing.name IS NOT NULL THEN
2010 NEW.name = existing.name || NEW.name;
2014 -- Have we already done this place?
2015 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;
2017 -- Get the existing place_id
2018 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;
2020 -- Handle a place changing type by removing the old data
2021 -- My generated 'place' types are causing havok because they overlap with real keys
2022 -- TODO: move them to their own special purpose key/class to avoid collisions
2023 IF existing.osm_type IS NULL THEN
2024 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2027 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2028 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2031 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2032 AND st_area(existing.geometry) > 0.02
2033 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2034 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2036 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
2037 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2041 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2042 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2044 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2045 IF existingplacex.osm_type IS NULL OR
2046 (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
2049 IF existingplacex.osm_type IS NOT NULL THEN
2050 -- sanity check: ignore admin_level changes on places with too many active children
2051 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2052 --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;
2053 --LIMIT INDEXING: IF i > 100000 THEN
2054 --LIMIT INDEXING: RETURN null;
2055 --LIMIT INDEXING: END IF;
2058 IF existing.osm_type IS NOT NULL THEN
2059 -- pathological case caused by the triggerless copy into place during initial import
2060 -- force delete even for large areas, it will be reinserted later
2061 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;
2062 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2065 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2066 insert into placex (osm_type, osm_id, class, type, name,
2067 admin_level, address, extratags, geometry)
2068 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2069 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2071 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2076 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2077 IF existing.geometry::text != NEW.geometry::text
2078 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2079 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2082 -- Get the version of the geometry actually used (in placex table)
2083 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;
2085 -- Performance limit
2086 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2088 -- 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
2089 update placex set indexed_status = 2 where indexed_status = 0 and
2090 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2091 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2092 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2094 update placex set indexed_status = 2 where indexed_status = 0 and
2095 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2096 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2097 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2104 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2105 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2106 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2107 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2108 OR existing.geometry::text != NEW.geometry::text
2113 address = NEW.address,
2114 extratags = NEW.extratags,
2115 admin_level = NEW.admin_level,
2116 geometry = NEW.geometry
2117 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2120 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2121 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2122 -- postcode was deleted, no longer retain in placex
2123 DELETE FROM placex where place_id = existingplacex.place_id;
2127 NEW.name := hstore('ref', NEW.address->'postcode');
2132 address = NEW.address,
2133 parent_place_id = null,
2134 extratags = NEW.extratags,
2135 admin_level = NEW.admin_level,
2137 geometry = NEW.geometry
2138 where place_id = existingplacex.place_id;
2140 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2141 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2142 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2143 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2144 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);
2149 -- Abort the add (we modified the existing place instead)
2154 $$ LANGUAGE plpgsql;
2157 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2162 IF name is null THEN
2166 FOR j IN 1..array_upper(languagepref,1) LOOP
2167 IF name ? languagepref[j] THEN
2168 result := trim(name->languagepref[j]);
2169 IF result != '' THEN
2175 -- anything will do as a fallback - just take the first name type thing there is
2176 RETURN trim((avals(name))[1]);
2179 LANGUAGE plpgsql IMMUTABLE;
2182 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2193 search := ARRAY['ref'];
2196 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2199 select rank_address,name,distance,length(name::text) as namelength
2200 from place_addressline join placex on (address_place_id = placex.place_id)
2201 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2202 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2204 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2205 FOR j IN 1..array_upper(search, 1) LOOP
2206 FOR k IN 1..array_upper(location.name, 1) LOOP
2207 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
2208 result[(100 - location.rank_address)] := trim(location.name[k].value);
2209 found := location.rank_address;
2216 RETURN array_to_string(result,', ');
2221 --housenumber only needed for tiger data
2222 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2234 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2235 currresult := trim(get_name_by_language(location.name, languagepref));
2236 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2237 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2238 prevresult := currresult;
2242 RETURN array_to_string(result,', ');
2247 DROP TYPE IF EXISTS addressline CASCADE;
2248 create type addressline as (
2255 admin_level INTEGER,
2258 rank_address INTEGER,
2262 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2265 for_place_id BIGINT;
2270 countrylocation RECORD;
2271 searchcountrycode varchar(2);
2272 searchhousenumber TEXT;
2273 searchhousename HSTORE;
2274 searchrankaddress INTEGER;
2275 searchpostcode TEXT;
2281 -- first query osmline (interpolation lines)
2282 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2283 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2284 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2285 IF for_place_id IS NOT NULL THEN
2286 searchhousenumber = in_housenumber::text;
2289 --then query tiger data
2290 -- %NOTIGERDATA% IF 0 THEN
2291 IF for_place_id IS NULL THEN
2292 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2293 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2294 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2295 IF for_place_id IS NOT NULL THEN
2296 searchhousenumber = in_housenumber::text;
2299 -- %NOTIGERDATA% END IF;
2301 -- %NOAUXDATA% IF 0 THEN
2302 IF for_place_id IS NULL THEN
2303 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2304 WHERE place_id = in_place_id
2305 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2307 -- %NOAUXDATA% END IF;
2309 IF for_place_id IS NULL THEN
2310 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2311 WHERE place_id = in_place_id and rank_search > 27
2312 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2315 IF for_place_id IS NULL THEN
2316 select coalesce(linked_place_id, place_id), country_code,
2317 housenumber, rank_search, postcode, null
2318 from placex where place_id = in_place_id
2319 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2322 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2325 hadcountry := false;
2327 select placex.place_id, osm_type, osm_id,
2328 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2329 class, type, admin_level, true as fromarea, true as isaddress,
2330 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2331 0 as distance, country_code, postcode
2333 where place_id = for_place_id
2335 --RAISE WARNING '%',location;
2336 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2337 searchcountrycode := location.country_code;
2339 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2340 location.isaddress := FALSE;
2342 IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
2343 searchpostcode := location.postcode;
2345 IF location.rank_address = 4 AND location.isaddress THEN
2348 IF location.rank_address < 4 AND NOT hadcountry THEN
2349 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2350 IF countryname IS NOT NULL THEN
2351 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2352 RETURN NEXT countrylocation;
2355 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2356 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2357 location.distance)::addressline;
2358 RETURN NEXT countrylocation;
2359 found := location.rank_address;
2363 select placex.place_id, osm_type, osm_id,
2364 CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
2365 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2366 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2367 admin_level, fromarea, isaddress,
2368 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,
2369 distance,country_code,postcode
2370 from place_addressline join placex on (address_place_id = placex.place_id)
2371 where place_addressline.place_id = for_place_id
2372 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2373 and address_place_id != for_place_id
2374 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2375 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2377 --RAISE WARNING '%',location;
2378 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2379 searchcountrycode := location.country_code;
2381 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2382 location.isaddress := FALSE;
2384 IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
2385 searchpostcode := location.postcode;
2387 IF location.rank_address = 4 AND location.isaddress THEN
2390 IF location.rank_address < 4 AND NOT hadcountry THEN
2391 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2392 IF countryname IS NOT NULL THEN
2393 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2394 RETURN NEXT countrylocation;
2397 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2398 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2399 location.distance)::addressline;
2400 RETURN NEXT countrylocation;
2401 found := location.rank_address;
2405 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2406 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2407 IF countryname IS NOT NULL THEN
2408 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2409 RETURN NEXT location;
2413 IF searchcountrycode IS NOT NULL THEN
2414 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2415 RETURN NEXT location;
2418 IF searchhousename IS NOT NULL THEN
2419 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2420 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2421 RETURN NEXT location;
2424 IF searchhousenumber IS NOT NULL THEN
2425 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2426 RETURN NEXT location;
2429 IF searchpostcode IS NOT NULL THEN
2430 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2431 RETURN NEXT location;
2440 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2446 ELSEIF rank < 4 THEN
2448 ELSEIF rank < 8 THEN
2450 ELSEIF rank < 12 THEN
2452 ELSEIF rank < 16 THEN
2454 ELSEIF rank = 16 THEN
2456 ELSEIF rank = 17 THEN
2457 RETURN 'Town / Island';
2458 ELSEIF rank = 18 THEN
2459 RETURN 'Village / Hamlet';
2460 ELSEIF rank = 20 THEN
2462 ELSEIF rank = 21 THEN
2463 RETURN 'Postcode Area';
2464 ELSEIF rank = 22 THEN
2465 RETURN 'Croft / Farm / Locality / Islet';
2466 ELSEIF rank = 23 THEN
2467 RETURN 'Postcode Area';
2468 ELSEIF rank = 25 THEN
2469 RETURN 'Postcode Point';
2470 ELSEIF rank = 26 THEN
2471 RETURN 'Street / Major Landmark';
2472 ELSEIF rank = 27 THEN
2473 RETURN 'Minory Street / Path';
2474 ELSEIF rank = 28 THEN
2475 RETURN 'House / Building';
2477 RETURN 'Other: '||rank;
2484 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2490 ELSEIF rank < 2 THEN
2492 ELSEIF rank < 4 THEN
2494 ELSEIF rank = 5 THEN
2496 ELSEIF rank < 8 THEN
2498 ELSEIF rank < 12 THEN
2500 ELSEIF rank < 16 THEN
2502 ELSEIF rank = 16 THEN
2504 ELSEIF rank = 17 THEN
2505 RETURN 'Town / Village / Hamlet';
2506 ELSEIF rank = 20 THEN
2508 ELSEIF rank = 21 THEN
2509 RETURN 'Postcode Area';
2510 ELSEIF rank = 22 THEN
2511 RETURN 'Croft / Farm / Locality / Islet';
2512 ELSEIF rank = 23 THEN
2513 RETURN 'Postcode Area';
2514 ELSEIF rank = 25 THEN
2515 RETURN 'Postcode Point';
2516 ELSEIF rank = 26 THEN
2517 RETURN 'Street / Major Landmark';
2518 ELSEIF rank = 27 THEN
2519 RETURN 'Minory Street / Path';
2520 ELSEIF rank = 28 THEN
2521 RETURN 'House / Building';
2523 RETURN 'Other: '||rank;
2530 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2531 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2536 place_centroid GEOMETRY;
2537 out_partition INTEGER;
2538 out_parent_place_id BIGINT;
2540 address_street_word_id INTEGER;
2545 place_centroid := ST_Centroid(pointgeo);
2546 out_partition := get_partition(in_countrycode);
2547 out_parent_place_id := null;
2549 address_street_word_id := get_name_id(make_standard_name(in_street));
2550 IF address_street_word_id IS NOT NULL THEN
2551 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2552 out_parent_place_id := location.place_id;
2556 IF out_parent_place_id IS NULL THEN
2557 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2558 out_parent_place_id := location.place_id;
2562 out_postcode := in_postcode;
2563 IF out_postcode IS NULL THEN
2564 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2566 IF out_postcode IS NULL THEN
2567 out_postcode := getNearestPostcode(out_partition, place_centroid);
2571 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2572 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2573 newpoints := newpoints + 1;
2580 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2587 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2588 IF members[i+1] = member THEN
2589 result := result || members[i];
2598 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2604 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2605 IF members[i+1] = ANY(memberLabels) THEN
2606 RETURN NEXT members[i];
2615 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2616 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2618 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2619 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
2620 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2621 ), '') AS bytea), 'UTF8');
2623 LANGUAGE SQL IMMUTABLE STRICT;
2625 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2629 RETURN decode_url_part(p);
2631 WHEN others THEN return null;
2634 LANGUAGE plpgsql IMMUTABLE;
2636 DROP TYPE wikipedia_article_match CASCADE;
2637 create type wikipedia_article_match as (
2643 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2649 wiki_article_title TEXT;
2650 wiki_article_language TEXT;
2651 result wikipedia_article_match;
2653 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'];
2655 WHILE langs[i] IS NOT NULL LOOP
2656 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2657 IF wiki_article is not null THEN
2658 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2659 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2660 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2661 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2662 wiki_article := replace(wiki_article,' ','_');
2663 IF strpos(wiki_article, ':') IN (3,4) THEN
2664 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2665 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2667 wiki_article_title := trim(wiki_article);
2668 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;
2671 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2672 from wikipedia_article
2673 where language = wiki_article_language and
2674 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2676 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2677 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2678 where wikipedia_redirect.language = wiki_article_language and
2679 (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'\\',''))
2680 order by importance desc limit 1 INTO result;
2682 IF result.language is not null THEN
2693 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2694 RETURNS SETOF GEOMETRY
2708 remainingdepth INTEGER;
2713 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2715 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2716 RETURN NEXT geometry;
2720 remainingdepth := maxdepth - 1;
2721 area := ST_AREA(geometry);
2722 IF remainingdepth < 1 OR area < maxarea THEN
2723 RETURN NEXT geometry;
2727 xmin := st_xmin(geometry);
2728 xmax := st_xmax(geometry);
2729 ymin := st_ymin(geometry);
2730 ymax := st_ymax(geometry);
2731 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2733 -- if the geometry completely covers the box don't bother to slice any more
2734 IF ST_AREA(secbox) = area THEN
2735 RETURN NEXT geometry;
2739 xmid := (xmin+xmax)/2;
2740 ymid := (ymin+ymax)/2;
2743 FOR seg IN 1..4 LOOP
2746 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2749 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2752 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2755 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2758 IF st_intersects(geometry, secbox) THEN
2759 secgeo := st_intersection(geometry, secbox);
2760 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2761 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2762 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2764 RETURN NEXT geo.geom;
2776 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2777 RETURNS SETOF GEOMETRY
2782 -- 10000000000 is ~~ 1x1 degree
2783 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2784 RETURN NEXT geo.geom;
2792 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2796 osmtype character(1);
2800 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2801 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2802 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2803 -- force delete from place/placex by making it a very small geometry
2804 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;
2805 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2812 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2820 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2821 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2822 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2823 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2824 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2825 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2826 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) = 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
2827 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2828 AND rank_search > rank and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (rank >= 16 and addr_place is not null));
2834 ELSEIF rank < 18 THEN
2836 ELSEIF rank < 20 THEN
2838 ELSEIF rank = 21 THEN
2840 ELSEIF rank < 24 THEN
2842 ELSEIF rank < 26 THEN
2843 diameter := 0.002; -- 100 to 200 meters
2844 ELSEIF rank < 28 THEN
2845 diameter := 0.001; -- 50 to 100 meters
2847 IF diameter > 0 THEN
2849 -- roads may cause reparenting for >27 rank places
2850 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2851 ELSEIF rank >= 16 THEN
2852 -- up to rank 16, street-less addresses may need reparenting
2853 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter) and (rank_search < 28 or name is not null or addr_place is not null);
2855 -- for all other places the search terms may change as well
2856 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);