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 := public.gettokenstring(public.transliteration(name));
39 RETURN trim(substr(o,1,length(o)));
42 LANGUAGE 'plpgsql' IMMUTABLE;
44 -- returns NULL if the word is too common
45 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
50 return_word_id INTEGER;
53 lookup_token := trim(lookup_word);
54 SELECT min(word_id), max(search_name_count) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id, count;
55 IF return_word_id IS NULL THEN
56 return_word_id := nextval('seq_word');
57 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, 0);
59 IF count > get_maxwordfreq() THEN
60 return_word_id := NULL;
63 RETURN return_word_id;
68 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
73 return_word_id INTEGER;
75 lookup_token := ' '||trim(lookup_word);
76 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
77 IF return_word_id IS NULL THEN
78 return_word_id := nextval('seq_word');
79 INSERT INTO word VALUES (return_word_id, lookup_token, null, 'place', 'house', null, 0);
81 RETURN return_word_id;
86 CREATE OR REPLACE FUNCTION getorcreate_postcode_id(postcode TEXT)
92 return_word_id INTEGER;
94 lookup_word := upper(trim(postcode));
95 lookup_token := ' ' || make_standard_name(lookup_word);
96 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='postcode' into return_word_id;
97 IF return_word_id IS NULL THEN
98 return_word_id := nextval('seq_word');
99 INSERT INTO word VALUES (return_word_id, lookup_token, lookup_word, 'place', 'postcode', null, 0);
101 RETURN return_word_id;
106 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
111 return_word_id INTEGER;
113 lookup_token := ' '||trim(lookup_word);
114 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
115 IF return_word_id IS NULL THEN
116 return_word_id := nextval('seq_word');
117 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, lookup_country_code, 0);
119 RETURN return_word_id;
124 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
129 return_word_id INTEGER;
131 lookup_token := ' '||trim(lookup_word);
132 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type into return_word_id;
133 IF return_word_id IS NULL THEN
134 return_word_id := nextval('seq_word');
135 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
137 RETURN return_word_id;
142 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
147 return_word_id INTEGER;
149 lookup_token := ' '||trim(lookup_word);
150 SELECT min(word_id) FROM word WHERE word_token = lookup_token and word=normalized_word and class=lookup_class and type = lookup_type and operator = op into return_word_id;
151 IF return_word_id IS NULL THEN
152 return_word_id := nextval('seq_word');
153 INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
155 RETURN return_word_id;
160 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
165 nospace_lookup_token TEXT;
166 return_word_id INTEGER;
168 lookup_token := ' '||trim(lookup_word);
169 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
170 IF return_word_id IS NULL THEN
171 return_word_id := nextval('seq_word');
172 INSERT INTO word VALUES (return_word_id, lookup_token, src_word, null, null, null, 0);
173 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
174 -- IF ' '||nospace_lookup_token != lookup_token THEN
175 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
178 RETURN return_word_id;
183 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
188 RETURN getorcreate_name_id(lookup_word, '');
193 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
198 return_word_id INTEGER;
200 lookup_token := trim(lookup_word);
201 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
202 RETURN return_word_id;
205 LANGUAGE plpgsql IMMUTABLE;
207 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
212 return_word_id INTEGER;
214 lookup_token := ' '||trim(lookup_word);
215 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
216 RETURN return_word_id;
219 LANGUAGE plpgsql IMMUTABLE;
221 CREATE OR REPLACE FUNCTION get_name_ids(lookup_word TEXT)
226 return_word_ids INTEGER[];
228 lookup_token := ' '||trim(lookup_word);
229 SELECT array_agg(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids;
230 RETURN return_word_ids;
233 LANGUAGE plpgsql IMMUTABLE;
235 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
242 IF array_upper(a, 1) IS NULL THEN
245 IF array_upper(b, 1) IS NULL THEN
249 FOR i IN 1..array_upper(b, 1) LOOP
250 IF NOT (ARRAY[b[i]] <@ r) THEN
257 LANGUAGE plpgsql IMMUTABLE;
259 CREATE OR REPLACE FUNCTION reverse_place_diameter(rank_search SMALLINT)
263 IF rank_search <= 4 THEN
265 ELSIF rank_search <= 8 THEN
267 ELSIF rank_search <= 12 THEN
269 ELSIF rank_search <= 17 THEN
271 ELSIF rank_search <= 18 THEN
273 ELSIF rank_search <= 19 THEN
280 LANGUAGE plpgsql IMMUTABLE;
282 CREATE OR REPLACE FUNCTION get_postcode_rank(country_code VARCHAR(2), postcode TEXT,
283 OUT rank_search SMALLINT, OUT rank_address SMALLINT)
290 postcode := upper(postcode);
292 IF country_code = 'gb' THEN
293 IF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
296 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
299 ELSEIF postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
304 ELSEIF country_code = 'sg' THEN
305 IF postcode ~ '^([0-9]{6})$' THEN
310 ELSEIF country_code = 'de' THEN
311 IF postcode ~ '^([0-9]{5})$' THEN
317 -- Guess at the postcode format and coverage (!)
318 IF postcode ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
322 -- Does it look splitable into and area and local code?
323 part := substring(postcode from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
325 IF part IS NOT NULL THEN
328 ELSEIF postcode ~ '^[- :A-Z0-9]{6,}$' THEN
337 LANGUAGE plpgsql IMMUTABLE;
339 -- Find the nearest artificial postcode for the given geometry.
340 -- TODO For areas there should not be more than two inside the geometry.
341 CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY) RETURNS TEXT
347 -- If the geometry is an area then only one postcode must be within
348 -- that area, otherwise consider the area as not having a postcode.
349 IF ST_GeometryType(geom) in ('ST_Polygon','ST_MultiPolygon') THEN
350 SELECT min(postcode), count(*) FROM
351 (SELECT postcode FROM location_postcode
352 WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
362 SELECT postcode FROM location_postcode
363 WHERE ST_DWithin(geom, location_postcode.geometry, 0.05)
364 AND location_postcode.country_code = country
365 ORDER BY ST_Distance(geom, location_postcode.geometry) LIMIT 1
374 CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
383 FOR item IN SELECT (each(src)).* LOOP
385 s := make_standard_name(item.value);
386 w := getorcreate_country(s, lookup_country_code);
388 words := regexp_split_to_array(item.value, E'[,;()]');
389 IF array_upper(words, 1) != 1 THEN
390 FOR j IN 1..array_upper(words, 1) LOOP
391 s := make_standard_name(words[j]);
393 w := getorcreate_country(s, lookup_country_code);
402 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
412 result := '{}'::INTEGER[];
414 FOR item IN SELECT (each(src)).* LOOP
416 s := make_standard_name(item.value);
418 w := getorcreate_name_id(s, item.value);
420 IF not(ARRAY[w] <@ result) THEN
421 result := result || w;
424 w := getorcreate_word_id(s);
426 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
427 result := result || w;
430 words := string_to_array(s, ' ');
431 IF array_upper(words, 1) IS NOT NULL THEN
432 FOR j IN 1..array_upper(words, 1) LOOP
433 IF (words[j] != '') THEN
434 w = getorcreate_word_id(words[j]);
435 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
436 result := result || w;
442 words := regexp_split_to_array(item.value, E'[,;()]');
443 IF array_upper(words, 1) != 1 THEN
444 FOR j IN 1..array_upper(words, 1) LOOP
445 s := make_standard_name(words[j]);
447 w := getorcreate_word_id(s);
448 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
449 result := result || w;
455 s := regexp_replace(item.value, '市$', '');
456 IF s != item.value THEN
457 s := make_standard_name(s);
459 w := getorcreate_name_id(s, item.value);
460 IF NOT (ARRAY[w] <@ result) THEN
461 result := result || w;
471 LANGUAGE plpgsql IMMUTABLE;
473 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
483 result := '{}'::INTEGER[];
485 s := make_standard_name(src);
486 w := getorcreate_name_id(s, src);
488 IF NOT (ARRAY[w] <@ result) THEN
489 result := result || w;
492 w := getorcreate_word_id(s);
494 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
495 result := result || w;
498 words := string_to_array(s, ' ');
499 IF array_upper(words, 1) IS NOT NULL THEN
500 FOR j IN 1..array_upper(words, 1) LOOP
501 IF (words[j] != '') THEN
502 w = getorcreate_word_id(words[j]);
503 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
504 result := result || w;
510 words := regexp_split_to_array(src, E'[,;()]');
511 IF array_upper(words, 1) != 1 THEN
512 FOR j IN 1..array_upper(words, 1) LOOP
513 s := make_standard_name(words[j]);
515 w := getorcreate_word_id(s);
516 IF w IS NOT NULL AND NOT (ARRAY[w] <@ result) THEN
517 result := result || w;
523 s := regexp_replace(src, '市$', '');
525 s := make_standard_name(s);
527 w := getorcreate_name_id(s, src);
528 IF NOT (ARRAY[w] <@ result) THEN
529 result := result || w;
537 LANGUAGE plpgsql IMMUTABLE;
539 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
542 place_centre GEOMETRY;
545 place_centre := ST_PointOnSurface(place);
547 -- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
549 -- Try for a OSM polygon
550 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
552 RETURN nearcountry.country_code;
555 -- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
557 -- Try for OSM fallback data
558 -- The order is to deal with places like HongKong that are 'states' within another polygon
559 FOR nearcountry IN select country_code from country_osm_grid where st_covers(geometry, place_centre) order by area asc limit 1
561 RETURN nearcountry.country_code;
564 -- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
567 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
569 RETURN nearcountry.country_code;
575 LANGUAGE plpgsql IMMUTABLE;
577 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
582 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
584 RETURN lower(nearcountry.country_default_language_code);
589 LANGUAGE plpgsql IMMUTABLE;
591 CREATE OR REPLACE FUNCTION get_country_language_codes(search_country_code VARCHAR(2)) RETURNS TEXT[]
596 FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
598 RETURN lower(nearcountry.country_default_language_codes);
603 LANGUAGE plpgsql IMMUTABLE;
605 CREATE OR REPLACE FUNCTION get_partition(in_country_code VARCHAR(10)) RETURNS INTEGER
610 FOR nearcountry IN select partition from country_name where country_code = in_country_code
612 RETURN nearcountry.partition;
617 LANGUAGE plpgsql IMMUTABLE;
619 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
623 DELETE FROM location_area where place_id = OLD_place_id;
624 -- TODO:location_area
630 CREATE OR REPLACE FUNCTION add_location(
632 country_code varchar(2),
636 rank_address INTEGER,
652 IF rank_search > 25 THEN
653 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
656 x := deleteLocationArea(partition, place_id, rank_search);
658 -- add postcode only if it contains a single entry, i.e. ignore postcode lists
660 IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
661 postcode := upper(trim (in_postcode));
664 IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
665 centroid := ST_Centroid(geometry);
667 FOR secgeo IN select split_geometry(geometry) AS geom LOOP
668 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
674 IF rank_address = 0 THEN
676 ELSEIF rank_search <= 14 THEN
678 ELSEIF rank_search <= 15 THEN
680 ELSEIF rank_search <= 16 THEN
682 ELSEIF rank_search <= 17 THEN
684 ELSEIF rank_search <= 21 THEN
686 ELSEIF rank_search = 25 THEN
690 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
692 secgeo := ST_Buffer(geometry, diameter);
693 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
703 -- find the parent road of the cut road parts
704 CREATE OR REPLACE FUNCTION get_interpolation_parent(wayid BIGINT, street TEXT, place TEXT,
705 partition INTEGER, centroid GEOMETRY, geom GEOMETRY)
710 parent_place_id BIGINT;
711 address_street_word_ids INTEGER[];
717 addr_street = street;
720 IF addr_street is null and addr_place is null THEN
721 select nodes from planet_osm_ways where id = wayid INTO waynodes;
722 FOR location IN SELECT placex.address from placex
723 where osm_type = 'N' and osm_id = ANY(waynodes)
724 and placex.address is not null
725 and (placex.address ? 'street' or placex.address ? 'place')
726 and indexed_status < 100
728 addr_street = location.address->'street';
729 addr_place = location.address->'place';
733 IF addr_street IS NOT NULL THEN
734 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
735 IF address_street_word_ids IS NOT NULL THEN
736 FOR location IN SELECT place_id from getNearestNamedRoadFeature(partition, centroid, address_street_word_ids) LOOP
737 parent_place_id := location.place_id;
742 IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
743 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
744 IF address_street_word_ids IS NOT NULL THEN
745 FOR location IN SELECT place_id from getNearestNamedPlaceFeature(partition, centroid, address_street_word_ids) LOOP
746 parent_place_id := location.place_id;
751 IF parent_place_id is null THEN
752 FOR location IN SELECT place_id FROM placex
753 WHERE ST_DWithin(geom, placex.geometry, 0.001) and placex.rank_search = 26
754 ORDER BY (ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0))+
755 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,0.5))+
756 ST_distance(placex.geometry, ST_LineInterpolatePoint(geom,1))) ASC limit 1
758 parent_place_id := location.place_id;
762 IF parent_place_id is null THEN
766 RETURN parent_place_id;
772 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
775 NEW.place_id := nextval('seq_place');
776 NEW.indexed_date := now();
778 IF NEW.indexed_status IS NULL THEN
779 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
780 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
781 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
785 NEW.indexed_status := 1; --STATUS_NEW
786 NEW.country_code := lower(get_country_code(NEW.linegeo));
788 NEW.partition := get_partition(NEW.country_code);
789 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
798 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
805 country_code VARCHAR(2);
806 default_language VARCHAR(10);
811 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
813 NEW.place_id := nextval('seq_place');
814 NEW.indexed_status := 1; --STATUS_NEW
816 NEW.country_code := lower(get_country_code(NEW.geometry));
818 NEW.partition := get_partition(NEW.country_code);
819 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
821 -- copy 'name' to or from the default language (if there is a default language)
822 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
823 default_language := get_country_language_code(NEW.country_code);
824 IF default_language IS NOT NULL THEN
825 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
826 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
827 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
828 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
833 IF NEW.osm_type = 'X' THEN
834 -- E'X'ternal records should already be in the right format so do nothing
836 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
838 IF NEW.class in ('place','boundary')
839 AND NEW.type in ('postcode','postal_code') THEN
841 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
842 -- most likely just a part of a multipolygon postcode boundary, throw it away
846 NEW.name := hstore('ref', NEW.address->'postcode');
848 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
849 INTO NEW.rank_search, NEW.rank_address;
852 NEW.rank_address := 0;
854 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
856 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
858 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
859 NEW.rank_search = 30;
860 NEW.rank_address = 0;
861 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
862 NEW.rank_search = 30;
863 NEW.rank_address = 0;
865 -- do table lookup stuff
866 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
867 classtype = NEW.type || NEW.admin_level::TEXT;
869 classtype = NEW.type;
871 SELECT l.rank_search, l.rank_address FROM address_levels l
872 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
873 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
874 ORDER BY l.country_code, l.class, l.type LIMIT 1
875 INTO NEW.rank_search, NEW.rank_address;
877 IF NEW.rank_search is NULL THEN
878 NEW.rank_search := 30;
881 IF NEW.rank_address is NULL THEN
882 NEW.rank_address := 30;
886 -- some postcorrections
887 IF NEW.class = 'place' THEN
888 IF NEW.type in ('continent', 'sea', 'country', 'state') AND NEW.osm_type = 'N' THEN
889 NEW.rank_address := 0;
891 ELSEIF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
892 -- Slightly promote waterway relations so that they are processed
893 -- before their members.
894 NEW.rank_search := NEW.rank_search - 1;
897 IF (NEW.extratags -> 'capital') = 'yes' THEN
898 NEW.rank_search := NEW.rank_search - 1;
903 -- a country code make no sense below rank 4 (country)
904 IF NEW.rank_search < 4 THEN
905 NEW.country_code := NULL;
908 -- Block import below rank 22
909 -- IF NEW.rank_search > 22 THEN
913 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
915 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
917 IF NEW.rank_address > 0 THEN
918 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
919 -- Performance: We just can't handle re-indexing for country level changes
920 IF st_area(NEW.geometry) < 1 THEN
921 -- mark items within the geometry for re-indexing
922 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
924 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
925 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
926 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'));
927 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
928 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 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
933 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
934 IF NEW.type='postcode' THEN
936 ELSEIF NEW.rank_search < 16 THEN
938 ELSEIF NEW.rank_search < 18 THEN
940 ELSEIF NEW.rank_search < 20 THEN
942 ELSEIF NEW.rank_search = 21 THEN
944 ELSEIF NEW.rank_search < 24 THEN
946 ELSEIF NEW.rank_search < 26 THEN
947 diameter := 0.002; -- 100 to 200 meters
948 ELSEIF NEW.rank_search < 28 THEN
949 diameter := 0.001; -- 50 to 100 meters
952 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
953 IF NEW.rank_search >= 26 THEN
954 -- roads may cause reparenting for >27 rank places
955 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
956 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
957 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
958 ELSEIF NEW.rank_search >= 16 THEN
959 -- up to rank 16, street-less addresses may need reparenting
960 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');
962 -- for all other places the search terms may change as well
963 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);
970 -- add to tables for special search
971 -- Note: won't work on initial import because the classtype tables
972 -- do not yet exist. It won't hurt either.
973 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
974 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
976 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
977 USING NEW.place_id, ST_Centroid(NEW.geometry);
986 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
990 place_centroid GEOMETRY;
1000 interpol_postcode TEXT;
1004 IF OLD.indexed_status = 100 THEN
1005 delete from location_property_osmline where place_id = OLD.place_id;
1009 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1013 NEW.interpolationtype = NEW.address->'interpolation';
1015 place_centroid := ST_PointOnSurface(NEW.linegeo);
1016 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1017 NEW.address->'place',
1018 NEW.partition, place_centroid, NEW.linegeo);
1020 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1021 interpol_postcode := NEW.address->'postcode';
1022 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1024 interpol_postcode := NULL;
1027 -- if the line was newly inserted, split the line as necessary
1028 IF OLD.indexed_status = 1 THEN
1029 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1031 IF array_upper(waynodes, 1) IS NULL THEN
1035 linegeo := NEW.linegeo;
1036 startnumber := NULL;
1038 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1040 select osm_id, address, geometry
1041 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1042 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1043 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1044 IF nextnode.osm_id IS NOT NULL THEN
1045 --RAISE NOTICE 'place_id is not null';
1046 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1047 -- Make sure that the point is actually on the line. That might
1048 -- be a bit paranoid but ensures that the algorithm still works
1049 -- should osm2pgsql attempt to repair geometries.
1050 splitline := split_line_on_node(linegeo, nextnode.geometry);
1051 sectiongeo := ST_GeometryN(splitline, 1);
1052 linegeo := ST_GeometryN(splitline, 2);
1054 sectiongeo = linegeo;
1056 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1058 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1059 AND startnumber != endnumber
1060 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1062 IF (startnumber > endnumber) THEN
1063 housenum := endnumber;
1064 endnumber := startnumber;
1065 startnumber := housenum;
1066 sectiongeo := ST_Reverse(sectiongeo);
1069 -- determine postcode
1070 postcode := coalesce(interpol_postcode,
1071 prevnode.address->'postcode',
1072 nextnode.address->'postcode',
1075 IF postcode is NULL THEN
1076 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1078 IF postcode is NULL THEN
1079 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1082 IF NEW.startnumber IS NULL THEN
1083 NEW.startnumber := startnumber;
1084 NEW.endnumber := endnumber;
1085 NEW.linegeo := sectiongeo;
1086 NEW.postcode := upper(trim(postcode));
1088 insert into location_property_osmline
1089 (linegeo, partition, osm_id, parent_place_id,
1090 startnumber, endnumber, interpolationtype,
1091 address, postcode, country_code,
1092 geometry_sector, indexed_status)
1093 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1094 startnumber, endnumber, NEW.interpolationtype,
1095 NEW.address, postcode,
1096 NEW.country_code, NEW.geometry_sector, 0);
1100 -- early break if we are out of line string,
1101 -- might happen when a line string loops back on itself
1102 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1106 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1107 prevnode := nextnode;
1112 -- marking descendants for reparenting is not needed, because there are
1113 -- actually no descendants for interpolation lines
1119 -- Trigger for updates of location_postcode
1121 -- Computes the parent object the postcode most likely refers to.
1122 -- This will be the place that determines the address displayed when
1123 -- searching for this postcode.
1124 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1131 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1135 NEW.indexed_date = now();
1137 partition := get_partition(NEW.country_code);
1139 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1140 INTO NEW.rank_search, NEW.rank_address;
1142 NEW.parent_place_id = 0;
1145 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1146 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1148 NEW.parent_place_id = location.place_id;
1156 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1161 place_centroid GEOMETRY;
1163 search_maxdistance FLOAT[];
1164 search_mindistance FLOAT[];
1165 address_havelevel BOOLEAN[];
1172 relation_members TEXT[];
1174 linkedplacex RECORD;
1176 search_diameter FLOAT;
1177 search_prevdiameter FLOAT;
1178 search_maxrank INTEGER;
1179 address_maxrank INTEGER;
1180 address_street_word_id INTEGER;
1181 address_street_word_ids INTEGER[];
1182 parent_place_id_rank BIGINT;
1190 location_rank_search INTEGER;
1191 location_distance FLOAT;
1192 location_parent GEOMETRY;
1193 location_isaddress BOOLEAN;
1194 location_keywords INTEGER[];
1196 default_language TEXT;
1197 name_vector INTEGER[];
1198 nameaddress_vector INTEGER[];
1200 linked_node_id BIGINT;
1201 linked_importance FLOAT;
1202 linked_wikipedia TEXT;
1207 IF OLD.indexed_status = 100 THEN
1208 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1209 delete from placex where place_id = OLD.place_id;
1213 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1217 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1219 NEW.indexed_date = now();
1221 IF NOT %REVERSE-ONLY% THEN
1222 DELETE from search_name WHERE place_id = NEW.place_id;
1224 result := deleteSearchName(NEW.partition, NEW.place_id);
1225 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1226 result := deleteRoad(NEW.partition, NEW.place_id);
1227 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1228 UPDATE placex set linked_place_id = null, indexed_status = 2
1229 where linked_place_id = NEW.place_id;
1230 -- update not necessary for osmline, cause linked_place_id does not exist
1232 IF NEW.linked_place_id is not null THEN
1233 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1237 --DEBUG: RAISE WARNING 'Copy over address tags';
1238 IF NEW.address is not NULL THEN
1239 IF NEW.address ? 'conscriptionnumber' THEN
1240 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1241 IF NEW.address ? 'streetnumber' THEN
1242 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1243 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1245 NEW.housenumber := NEW.address->'conscriptionnumber';
1247 ELSEIF NEW.address ? 'streetnumber' THEN
1248 NEW.housenumber := NEW.address->'streetnumber';
1249 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1250 ELSEIF NEW.address ? 'housenumber' THEN
1251 NEW.housenumber := NEW.address->'housenumber';
1252 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1255 addr_street := NEW.address->'street';
1256 addr_place := NEW.address->'place';
1258 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1259 i := getorcreate_postcode_id(NEW.address->'postcode');
1263 -- Speed up searches - just use the centroid of the feature
1264 -- cheaper but less acurate
1265 place_centroid := ST_PointOnSurface(NEW.geometry);
1266 NEW.centroid := null;
1267 NEW.postcode := null;
1268 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1270 -- recalculate country and partition
1271 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1272 -- for countries, believe the mapped country code,
1273 -- so that we remain in the right partition if the boundaries
1275 NEW.country_code := lower(NEW.address->'country');
1276 NEW.partition := get_partition(lower(NEW.country_code));
1277 IF NEW.partition = 0 THEN
1278 NEW.country_code := lower(get_country_code(place_centroid));
1279 NEW.partition := get_partition(NEW.country_code);
1282 IF NEW.rank_search >= 4 THEN
1283 NEW.country_code := lower(get_country_code(place_centroid));
1285 NEW.country_code := NULL;
1287 NEW.partition := get_partition(NEW.country_code);
1289 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1291 -- waterway ways are linked when they are part of a relation and have the same class/type
1292 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1293 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1295 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1296 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1297 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1298 FOR linked_node_id IN SELECT place_id FROM placex
1299 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1300 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1301 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1303 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1308 --DEBUG: RAISE WARNING 'Waterway processed';
1311 -- Adding ourselves to the list simplifies address calculations later
1312 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1313 VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1315 -- What level are we searching from
1316 search_maxrank := NEW.rank_search;
1318 -- Thought this wasn't needed but when we add new languages to the country_name table
1319 -- we need to update the existing names
1320 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1321 default_language := get_country_language_code(NEW.country_code);
1322 IF default_language IS NOT NULL THEN
1323 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1324 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1325 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1326 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1330 --DEBUG: RAISE WARNING 'Local names updated';
1332 -- Initialise the name vector using our name
1333 name_vector := make_keywords(NEW.name);
1334 nameaddress_vector := '{}'::int[];
1337 address_havelevel[i] := false;
1340 NEW.importance := null;
1341 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1342 IF NEW.importance IS NULL THEN
1343 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;
1346 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1348 -- ---------------------------------------------------------------------------
1349 -- For low level elements we inherit from our parent road
1350 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1352 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1354 -- We won't get a better centroid, besides these places are too small to care
1355 NEW.centroid := place_centroid;
1357 NEW.parent_place_id := null;
1359 -- if we have a POI and there is no address information,
1360 -- see if we can get it from a surrounding building
1361 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1362 AND NEW.housenumber IS NULL THEN
1363 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1364 and address is not null
1365 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1366 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1369 NEW.housenumber := location.address->'housenumber';
1370 addr_street := location.address->'street';
1371 addr_place := location.address->'place';
1372 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1376 -- We have to find our parent road.
1377 -- Copy data from linked items (points on ways, addr:street links, relations)
1379 -- Is this object part of a relation?
1380 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1382 -- At the moment we only process one type of relation - associatedStreet
1383 IF relation.tags @> ARRAY['associatedStreet'] THEN
1384 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1385 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1386 --RAISE WARNING 'node in relation %',relation;
1387 SELECT place_id from placex where osm_type = 'W'
1388 and osm_id = substring(relation.members[i],2,200)::bigint
1389 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1394 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1396 -- Note that addr:street links can only be indexed once the street itself is indexed
1397 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1398 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1399 IF address_street_word_ids IS NOT NULL THEN
1400 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1403 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1405 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1406 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1407 IF address_street_word_ids IS NOT NULL THEN
1408 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1411 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1413 -- Is this node part of an interpolation?
1414 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1415 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1416 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1417 LIMIT 1 INTO NEW.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
1425 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1426 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)
1428 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1430 -- Way IS a road then we are on it - that must be our road
1431 IF location.rank_search < 28 THEN
1432 --RAISE WARNING 'node in way that is a street %',location;
1433 NEW.parent_place_id := location.place_id;
1436 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1438 -- If the way mentions a street or place address, try that for parenting.
1439 IF location.address is not null THEN
1440 IF location.address ? 'street' THEN
1441 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1442 IF address_street_word_ids IS NOT NULL THEN
1443 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1444 EXIT WHEN NEW.parent_place_id is not NULL;
1447 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1449 IF location.address ? 'place' THEN
1450 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1451 IF address_street_word_ids IS NOT NULL THEN
1452 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1453 EXIT WHEN NEW.parent_place_id is not NULL;
1456 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1459 -- Is the WAY part of a relation
1460 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1462 -- At the moment we only process one type of relation - associatedStreet
1463 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1464 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1465 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1466 --RAISE WARNING 'node in way that is in a relation %',relation;
1467 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1468 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1473 EXIT WHEN NEW.parent_place_id is not null;
1474 --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 SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) INTO NEW.parent_place_id;
1483 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1486 -- If we didn't find any road fallback to standard method
1487 IF NEW.parent_place_id IS NOT NULL THEN
1489 -- Get the details of the parent road
1490 SELECT p.country_code, p.postcode FROM placex p
1491 WHERE p.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 -- determine postcode
1497 IF NEW.rank_search > 4 THEN
1498 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1499 NEW.postcode = upper(trim(NEW.address->'postcode'));
1501 NEW.postcode := location.postcode;
1503 IF NEW.postcode is null THEN
1504 NEW.postcode := get_nearest_postcode(NEW.country_code, place_centroid);
1508 -- If there is no name it isn't searchable, don't bother to create a search record
1509 IF NEW.name is NULL THEN
1510 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1514 -- Performance, it would be more acurate to do all the rest of the import
1515 -- process but it takes too long
1516 -- Just be happy with inheriting from parent road only
1517 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1518 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
1519 --DEBUG: RAISE WARNING 'Place added to location table';
1522 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1523 NEW.rank_search, NEW.rank_address, NEW.geometry);
1525 IF NOT %REVERSE-ONLY% THEN
1526 -- Merge address from parent
1527 SELECT s.name_vector, s.nameaddress_vector FROM search_name s
1528 WHERE s.place_id = NEW.parent_place_id INTO location;
1530 nameaddress_vector := array_merge(nameaddress_vector,
1531 location.nameaddress_vector);
1532 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1534 INSERT INTO search_name (place_id, search_rank, address_rank,
1535 importance, country_code, name_vector,
1536 nameaddress_vector, centroid)
1537 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1538 NEW.importance, NEW.country_code, name_vector,
1539 nameaddress_vector, place_centroid);
1540 --DEBUG: RAISE WARNING 'Place added to search table';
1548 -- ---------------------------------------------------------------------------
1550 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1552 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1554 -- see if we have any special relation members
1555 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1556 --DEBUG: RAISE WARNING 'Got relation members';
1558 IF relation_members IS NOT NULL THEN
1559 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1560 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1562 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1563 and osm_id = substring(relMember.member,2,10000)::bigint
1564 and class = 'place' order by rank_search desc limit 1 LOOP
1566 -- If we don't already have one use this as the centre point of the geometry
1567 IF NEW.centroid IS NULL THEN
1568 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1571 -- merge in the label name, re-init word vector
1572 IF NOT linkedPlacex.name IS NULL THEN
1573 NEW.name := linkedPlacex.name || NEW.name;
1574 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1577 -- merge in extra tags
1578 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1580 -- mark the linked place (excludes from search results)
1581 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1583 -- keep a note of the node id in case we need it for wikipedia in a bit
1584 linked_node_id := linkedPlacex.osm_id;
1585 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1586 --DEBUG: RAISE WARNING 'Linked label member';
1591 IF NEW.centroid IS NULL THEN
1593 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1594 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1596 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1597 and osm_id = substring(relMember.member,2,10000)::bigint
1598 and class = 'place' order by rank_search desc limit 1 LOOP
1600 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1601 -- But that can be fixed by explicitly setting the label in the data
1602 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1603 AND NEW.rank_address = linkedPlacex.rank_address THEN
1605 -- If we don't already have one use this as the centre point of the geometry
1606 IF NEW.centroid IS NULL THEN
1607 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1610 -- merge in the name, re-init word vector
1611 IF NOT linkedPlacex.name IS NULL THEN
1612 NEW.name := linkedPlacex.name || NEW.name;
1613 name_vector := make_keywords(NEW.name);
1616 -- merge in extra tags
1617 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1619 -- mark the linked place (excludes from search results)
1620 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1622 -- keep a note of the node id in case we need it for wikipedia in a bit
1623 linked_node_id := linkedPlacex.osm_id;
1624 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1625 --DEBUG: RAISE WARNING 'Linked admin_center';
1637 -- Name searches can be done for ways as well as relations
1638 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1640 -- not found one yet? how about doing a name search
1641 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1643 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1644 FOR linkedPlacex IN select placex.* from placex WHERE
1645 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1646 AND placex.rank_address = NEW.rank_address
1647 AND placex.place_id != NEW.place_id
1648 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1649 AND st_covers(NEW.geometry, placex.geometry)
1651 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1652 -- If we don't already have one use this as the centre point of the geometry
1653 IF NEW.centroid IS NULL THEN
1654 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1657 -- merge in the name, re-init word vector
1658 NEW.name := linkedPlacex.name || NEW.name;
1659 name_vector := make_keywords(NEW.name);
1661 -- merge in extra tags
1662 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1664 -- mark the linked place (excludes from search results)
1665 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1667 -- keep a note of the node id in case we need it for wikipedia in a bit
1668 linked_node_id := linkedPlacex.osm_id;
1669 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1670 --DEBUG: RAISE WARNING 'Linked named place';
1674 IF NEW.centroid IS NOT NULL THEN
1675 place_centroid := NEW.centroid;
1676 -- Place might have had only a name tag before but has now received translations
1677 -- from the linked place. Make sure a name tag for the default language exists in
1679 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1680 default_language := get_country_language_code(NEW.country_code);
1681 IF default_language IS NOT NULL THEN
1682 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1683 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1684 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1685 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1689 --DEBUG: RAISE WARNING 'Names updated from linked places';
1692 -- Use the maximum importance if a one could be computed from the linked object.
1693 IF linked_importance is not null AND
1694 (NEW.importance is null or NEW.importance < linked_importance) THEN
1695 NEW.importance = linked_importance;
1698 -- Still null? how about looking it up by the node id
1699 IF NEW.importance IS NULL THEN
1700 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1701 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;
1706 -- make sure all names are in the word table
1707 IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL AND NEW.osm_type = 'R' THEN
1708 perform create_country(NEW.name, lower(NEW.country_code));
1709 --DEBUG: RAISE WARNING 'Country names updated';
1712 NEW.parent_place_id = 0;
1713 parent_place_id_rank = 0;
1716 -- convert address store to array of tokenids
1717 --DEBUG: RAISE WARNING 'Starting address search';
1718 isin_tokens := '{}'::int[];
1719 IF NEW.address IS NOT NULL THEN
1720 FOR addr_item IN SELECT * FROM each(NEW.address)
1722 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1723 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1724 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1725 isin_tokens := isin_tokens || address_street_word_id;
1727 IF NOT %REVERSE-ONLY% THEN
1728 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1729 IF address_street_word_id IS NOT NULL THEN
1730 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1734 IF addr_item.key = 'is_in' THEN
1735 -- is_in items need splitting
1736 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1737 IF array_upper(isin, 1) IS NOT NULL THEN
1738 FOR i IN 1..array_upper(isin, 1) LOOP
1739 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1740 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1741 isin_tokens := isin_tokens || address_street_word_id;
1744 -- merge word into address vector
1745 IF NOT %REVERSE-ONLY% THEN
1746 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1747 IF address_street_word_id IS NOT NULL THEN
1748 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1756 IF NOT %REVERSE-ONLY% THEN
1757 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1760 -- RAISE WARNING 'ISIN: %', isin_tokens;
1762 -- Process area matches
1763 location_rank_search := 0;
1764 location_distance := 0;
1765 location_parent := NULL;
1766 -- added ourself as address already
1767 address_havelevel[NEW.rank_address] := true;
1768 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1770 SELECT * from getNearFeatures(NEW.partition,
1771 CASE WHEN NEW.rank_search >= 26
1772 AND NEW.rank_search < 30
1774 ELSE place_centroid END,
1775 search_maxrank, isin_tokens)
1777 IF location.rank_address != location_rank_search THEN
1778 location_rank_search := location.rank_address;
1779 IF location.isguess THEN
1780 location_distance := location.distance * 1.5;
1782 IF location.rank_address <= 12 THEN
1783 -- for county and above, if we have an area consider that exact
1784 -- (It would be nice to relax the constraint for places close to
1785 -- the boundary but we'd need the exact geometry for that. Too
1787 location_distance = 0;
1789 -- Below county level remain slightly fuzzy.
1790 location_distance := location.distance * 0.5;
1794 CONTINUE WHEN location.keywords <@ location_keywords;
1797 IF location.distance < location_distance OR NOT location.isguess THEN
1798 location_keywords := location.keywords;
1800 location_isaddress := NOT address_havelevel[location.rank_address];
1801 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1802 location_isaddress := ST_Contains(location_parent,location.centroid);
1805 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1806 -- Add it to the list of search terms
1807 IF NOT %REVERSE-ONLY% AND location.rank_search > 4 THEN
1808 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1810 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1811 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1813 IF location_isaddress THEN
1814 -- add postcode if we have one
1815 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1816 IF location.postcode is not null THEN
1817 NEW.postcode = location.postcode;
1820 address_havelevel[location.rank_address] := true;
1821 IF NOT location.isguess THEN
1822 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1825 IF location.rank_address > parent_place_id_rank THEN
1826 NEW.parent_place_id = location.place_id;
1827 parent_place_id_rank = location.rank_address;
1832 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1837 --DEBUG: RAISE WARNING 'address computed';
1839 IF NEW.address is not null AND NEW.address ? 'postcode'
1840 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1841 NEW.postcode := upper(trim(NEW.address->'postcode'));
1844 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1845 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1848 -- if we have a name add this to the name search table
1849 IF NEW.name IS NOT NULL THEN
1851 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1852 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, upper(trim(NEW.address->'postcode')), NEW.geometry);
1853 --DEBUG: RAISE WARNING 'added to location (full)';
1856 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1857 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1858 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1861 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1862 NEW.rank_search, NEW.rank_address, NEW.geometry);
1863 --DEBUG: RAISE WARNING 'added to search name (full)';
1865 IF NOT %REVERSE-ONLY% THEN
1866 INSERT INTO search_name (place_id, search_rank, address_rank,
1867 importance, country_code, name_vector,
1868 nameaddress_vector, centroid)
1869 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1870 NEW.importance, NEW.country_code, name_vector,
1871 nameaddress_vector, place_centroid);
1876 -- If we've not managed to pick up a better one - default centroid
1877 IF NEW.centroid IS NULL THEN
1878 NEW.centroid := place_centroid;
1881 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1888 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1894 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1896 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1897 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1898 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1899 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1901 IF OLD.rank_address < 30 THEN
1903 -- mark everything linked to this place for re-indexing
1904 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1905 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1906 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1908 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1909 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1911 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1912 b := deleteRoad(OLD.partition, OLD.place_id);
1914 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1915 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1916 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1917 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1918 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1922 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1924 IF OLD.rank_address < 26 THEN
1925 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1928 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1930 IF OLD.name is not null THEN
1931 IF NOT %REVERSE-ONLY% THEN
1932 DELETE from search_name WHERE place_id = OLD.place_id;
1934 b := deleteSearchName(OLD.partition, OLD.place_id);
1937 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1939 DELETE FROM place_addressline where place_id = OLD.place_id;
1941 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1943 -- remove from tables for special search
1944 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1945 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1947 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1950 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1958 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1964 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1966 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1967 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1968 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;
1970 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1976 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;
1978 -- interpolations are special
1979 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1980 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1989 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1994 existingplacex RECORD;
1995 existingline RECORD;
1996 existinggeometry GEOMETRY;
1997 existingplace_id BIGINT;
2002 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2003 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2004 -- filter wrong tupels
2005 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
2006 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2007 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2008 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2012 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2013 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
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 location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2020 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2021 IF existing.osm_type IS NULL THEN
2022 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2025 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2026 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2028 -- 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)
2029 IF existingline.osm_id IS NOT NULL THEN
2030 delete from location_property_osmline where osm_id = NEW.osm_id;
2033 -- for interpolations invalidate all nodes on the line
2034 update placex p set indexed_status = 2
2035 from planet_osm_ways w
2036 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2039 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2040 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2043 IF existing.osm_type IS NULL THEN
2047 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2048 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2049 OR existing.geometry::text != NEW.geometry::text
2054 address = NEW.address,
2055 extratags = NEW.extratags,
2056 admin_level = NEW.admin_level,
2057 geometry = NEW.geometry
2058 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2063 ELSE -- insert to placex
2065 -- Patch in additional country names
2066 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2067 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2068 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2069 IF existing.name IS NOT NULL THEN
2070 NEW.name = existing.name || NEW.name;
2074 -- Have we already done this place?
2075 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;
2077 -- Get the existing place_id
2078 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;
2080 -- Handle a place changing type by removing the old data
2081 -- My generated 'place' types are causing havok because they overlap with real keys
2082 -- TODO: move them to their own special purpose key/class to avoid collisions
2083 IF existing.osm_type IS NULL THEN
2084 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2087 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2088 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2091 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2092 AND st_area(existing.geometry) > 0.02
2093 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2094 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2096 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2097 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2098 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2102 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2103 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2105 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2106 IF existingplacex.osm_type IS NULL OR
2107 (existingplacex.class = 'boundary' AND
2108 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2109 (existingplacex.type != NEW.type)))
2112 IF existingplacex.osm_type IS NOT NULL THEN
2113 -- sanity check: ignore admin_level changes on places with too many active children
2114 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2115 --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;
2116 --LIMIT INDEXING: IF i > 100000 THEN
2117 --LIMIT INDEXING: RETURN null;
2118 --LIMIT INDEXING: END IF;
2121 IF existing.osm_type IS NOT NULL THEN
2122 -- pathological case caused by the triggerless copy into place during initial import
2123 -- force delete even for large areas, it will be reinserted later
2124 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;
2125 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2128 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2129 insert into placex (osm_type, osm_id, class, type, name,
2130 admin_level, address, extratags, geometry)
2131 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2132 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2134 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2139 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2140 IF existing.geometry::text != NEW.geometry::text
2141 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2142 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2145 -- Get the version of the geometry actually used (in placex table)
2146 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;
2148 -- Performance limit
2149 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2151 -- 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
2152 update placex set indexed_status = 2 where indexed_status = 0 and
2153 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2154 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2155 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2157 update placex set indexed_status = 2 where indexed_status = 0 and
2158 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2159 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2160 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2167 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2168 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2169 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2170 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2171 OR existing.geometry::text != NEW.geometry::text
2176 address = NEW.address,
2177 extratags = NEW.extratags,
2178 admin_level = NEW.admin_level,
2179 geometry = NEW.geometry
2180 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2183 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2184 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2185 -- postcode was deleted, no longer retain in placex
2186 DELETE FROM placex where place_id = existingplacex.place_id;
2190 NEW.name := hstore('ref', NEW.address->'postcode');
2193 IF NEW.class in ('boundary')
2194 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2195 DELETE FROM placex where place_id = existingplacex.place_id;
2201 address = NEW.address,
2202 parent_place_id = null,
2203 extratags = NEW.extratags,
2204 admin_level = NEW.admin_level,
2206 geometry = NEW.geometry
2207 where place_id = existingplacex.place_id;
2209 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2210 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2211 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2212 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2213 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);
2216 -- linked places should get potential new naming and addresses
2217 IF existingplacex.linked_place_id is not NULL THEN
2220 extratags = p.extratags,
2223 where x.place_id = existingplacex.linked_place_id
2224 and x.indexed_status = 0
2225 and x.osm_type = p.osm_type
2226 and x.osm_id = p.osm_id
2227 and x.class = p.class;
2232 -- Abort the add (we modified the existing place instead)
2237 $$ LANGUAGE plpgsql;
2240 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2245 IF name is null THEN
2249 FOR j IN 1..array_upper(languagepref,1) LOOP
2250 IF name ? languagepref[j] THEN
2251 result := trim(name->languagepref[j]);
2252 IF result != '' THEN
2258 -- anything will do as a fallback - just take the first name type thing there is
2259 RETURN trim((avals(name))[1]);
2262 LANGUAGE plpgsql IMMUTABLE;
2264 --housenumber only needed for tiger data
2265 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2277 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2278 currresult := trim(get_name_by_language(location.name, languagepref));
2279 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2280 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2281 prevresult := currresult;
2285 RETURN array_to_string(result,', ');
2290 DROP TYPE IF EXISTS addressline CASCADE;
2291 create type addressline as (
2298 admin_level INTEGER,
2301 rank_address INTEGER,
2305 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2308 for_place_id BIGINT;
2313 countrylocation RECORD;
2314 searchcountrycode varchar(2);
2315 searchhousenumber TEXT;
2316 searchhousename HSTORE;
2317 searchrankaddress INTEGER;
2318 searchpostcode TEXT;
2324 -- first query osmline (interpolation lines)
2325 select parent_place_id, country_code, 30, postcode, null, 'place', 'house' from location_property_osmline
2326 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2327 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2328 IF for_place_id IS NOT NULL THEN
2329 searchhousenumber = in_housenumber::text;
2332 --then query tiger data
2333 -- %NOTIGERDATA% IF 0 THEN
2334 IF for_place_id IS NULL THEN
2335 select parent_place_id,'us', 30, postcode, null, 'place', 'house' from location_property_tiger
2336 WHERE place_id = in_place_id AND in_housenumber>=startnumber AND in_housenumber <= endnumber
2337 INTO for_place_id,searchcountrycode, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2338 IF for_place_id IS NOT NULL THEN
2339 searchhousenumber = in_housenumber::text;
2342 -- %NOTIGERDATA% END IF;
2344 -- %NOAUXDATA% IF 0 THEN
2345 IF for_place_id IS NULL THEN
2346 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2347 WHERE place_id = in_place_id
2348 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2350 -- %NOAUXDATA% END IF;
2353 IF for_place_id IS NULL THEN
2354 select parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2355 FROM location_postcode
2356 WHERE place_id = in_place_id
2357 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode, searchclass, searchtype;
2360 IF for_place_id IS NULL THEN
2361 select parent_place_id, country_code, housenumber, rank_search, postcode, name, class, type from placex
2362 WHERE place_id = in_place_id and rank_search > 27
2363 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2366 IF for_place_id IS NULL THEN
2367 select coalesce(linked_place_id, place_id), country_code,
2368 housenumber, rank_search, postcode, null
2369 from placex where place_id = in_place_id
2370 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2373 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2376 hadcountry := false;
2378 select placex.place_id, osm_type, osm_id, name,
2379 class, type, admin_level, true as isaddress,
2380 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2381 0 as distance, country_code, postcode
2383 where place_id = for_place_id
2385 --RAISE WARNING '%',location;
2386 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2387 searchcountrycode := location.country_code;
2389 IF location.type in ('postcode', 'postal_code') THEN
2390 location.isaddress := FALSE;
2391 ELSEIF location.rank_address = 4 THEN
2394 IF location.rank_address < 4 AND NOT hadcountry THEN
2395 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2396 IF countryname IS NOT NULL THEN
2397 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2398 RETURN NEXT countrylocation;
2401 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2402 location.type, location.admin_level, true, location.isaddress, location.rank_address,
2403 location.distance)::addressline;
2404 RETURN NEXT countrylocation;
2405 found := location.rank_address;
2409 select placex.place_id, osm_type, osm_id, name,
2410 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2411 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2412 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
2413 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,
2414 distance,country_code,postcode
2415 from place_addressline join placex on (address_place_id = placex.place_id)
2416 where place_addressline.place_id = for_place_id
2417 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2418 and address_place_id != for_place_id and linked_place_id is null
2419 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode)
2420 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2422 --RAISE WARNING '%',location;
2423 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2424 searchcountrycode := location.country_code;
2426 IF location.type in ('postcode', 'postal_code') THEN
2427 location.isaddress := FALSE;
2429 IF location.rank_address = 4 AND location.isaddress THEN
2432 IF location.rank_address < 4 AND NOT hadcountry THEN
2433 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2434 IF countryname IS NOT NULL THEN
2435 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2436 RETURN NEXT countrylocation;
2439 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2440 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2441 location.distance)::addressline;
2442 RETURN NEXT countrylocation;
2443 found := location.rank_address;
2447 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2448 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2449 IF countryname IS NOT NULL THEN
2450 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2451 RETURN NEXT location;
2455 IF searchcountrycode IS NOT NULL THEN
2456 location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
2457 RETURN NEXT location;
2460 IF searchhousename IS NOT NULL THEN
2461 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2462 RETURN NEXT location;
2465 IF searchhousenumber IS NOT NULL THEN
2466 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
2467 RETURN NEXT location;
2470 IF searchpostcode IS NOT NULL THEN
2471 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
2472 RETURN NEXT location;
2481 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2487 ELSEIF rank < 4 THEN
2489 ELSEIF rank < 8 THEN
2491 ELSEIF rank < 12 THEN
2493 ELSEIF rank < 16 THEN
2495 ELSEIF rank = 16 THEN
2497 ELSEIF rank = 17 THEN
2498 RETURN 'Town / Island';
2499 ELSEIF rank = 18 THEN
2500 RETURN 'Village / Hamlet';
2501 ELSEIF rank = 20 THEN
2503 ELSEIF rank = 21 THEN
2504 RETURN 'Postcode Area';
2505 ELSEIF rank = 22 THEN
2506 RETURN 'Croft / Farm / Locality / Islet';
2507 ELSEIF rank = 23 THEN
2508 RETURN 'Postcode Area';
2509 ELSEIF rank = 25 THEN
2510 RETURN 'Postcode Point';
2511 ELSEIF rank = 26 THEN
2512 RETURN 'Street / Major Landmark';
2513 ELSEIF rank = 27 THEN
2514 RETURN 'Minory Street / Path';
2515 ELSEIF rank = 28 THEN
2516 RETURN 'House / Building';
2518 RETURN 'Other: '||rank;
2525 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2531 ELSEIF rank < 2 THEN
2533 ELSEIF rank < 4 THEN
2535 ELSEIF rank = 5 THEN
2537 ELSEIF rank < 8 THEN
2539 ELSEIF rank < 12 THEN
2541 ELSEIF rank < 16 THEN
2543 ELSEIF rank = 16 THEN
2545 ELSEIF rank = 17 THEN
2546 RETURN 'Town / Village / Hamlet';
2547 ELSEIF rank = 20 THEN
2549 ELSEIF rank = 21 THEN
2550 RETURN 'Postcode Area';
2551 ELSEIF rank = 22 THEN
2552 RETURN 'Croft / Farm / Locality / Islet';
2553 ELSEIF rank = 23 THEN
2554 RETURN 'Postcode Area';
2555 ELSEIF rank = 25 THEN
2556 RETURN 'Postcode Point';
2557 ELSEIF rank = 26 THEN
2558 RETURN 'Street / Major Landmark';
2559 ELSEIF rank = 27 THEN
2560 RETURN 'Minory Street / Path';
2561 ELSEIF rank = 28 THEN
2562 RETURN 'House / Building';
2564 RETURN 'Other: '||rank;
2571 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2572 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2577 place_centroid GEOMETRY;
2578 out_partition INTEGER;
2579 out_parent_place_id BIGINT;
2581 address_street_word_id INTEGER;
2586 place_centroid := ST_Centroid(pointgeo);
2587 out_partition := get_partition(in_countrycode);
2588 out_parent_place_id := null;
2590 address_street_word_id := get_name_id(make_standard_name(in_street));
2591 IF address_street_word_id IS NOT NULL THEN
2592 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2593 out_parent_place_id := location.place_id;
2597 IF out_parent_place_id IS NULL THEN
2598 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2599 out_parent_place_id := location.place_id;
2603 out_postcode := in_postcode;
2604 IF out_postcode IS NULL THEN
2605 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2607 -- XXX look into postcode table
2610 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2611 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2612 newpoints := newpoints + 1;
2619 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2626 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2627 IF members[i+1] = member THEN
2628 result := result || members[i];
2637 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2643 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2644 IF members[i+1] = ANY(memberLabels) THEN
2645 RETURN NEXT members[i];
2654 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2655 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2657 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2658 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
2659 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2660 ), '') AS bytea), 'UTF8');
2662 LANGUAGE SQL IMMUTABLE STRICT;
2664 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2668 RETURN decode_url_part(p);
2670 WHEN others THEN return null;
2673 LANGUAGE plpgsql IMMUTABLE;
2675 DROP TYPE wikipedia_article_match CASCADE;
2676 create type wikipedia_article_match as (
2682 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2688 wiki_article_title TEXT;
2689 wiki_article_language TEXT;
2690 result wikipedia_article_match;
2692 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'];
2694 WHILE langs[i] IS NOT NULL LOOP
2695 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2696 IF wiki_article is not null THEN
2697 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2698 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2699 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2700 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2701 wiki_article := replace(wiki_article,' ','_');
2702 IF strpos(wiki_article, ':') IN (3,4) THEN
2703 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2704 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2706 wiki_article_title := trim(wiki_article);
2707 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;
2710 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2711 from wikipedia_article
2712 where language = wiki_article_language and
2713 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2715 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2716 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2717 where wikipedia_redirect.language = wiki_article_language and
2718 (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'\\',''))
2719 order by importance desc limit 1 INTO result;
2721 IF result.language is not null THEN
2732 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2733 RETURNS SETOF GEOMETRY
2747 remainingdepth INTEGER;
2752 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2754 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2755 RETURN NEXT geometry;
2759 remainingdepth := maxdepth - 1;
2760 area := ST_AREA(geometry);
2761 IF remainingdepth < 1 OR area < maxarea THEN
2762 RETURN NEXT geometry;
2766 xmin := st_xmin(geometry);
2767 xmax := st_xmax(geometry);
2768 ymin := st_ymin(geometry);
2769 ymax := st_ymax(geometry);
2770 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2772 -- if the geometry completely covers the box don't bother to slice any more
2773 IF ST_AREA(secbox) = area THEN
2774 RETURN NEXT geometry;
2778 xmid := (xmin+xmax)/2;
2779 ymid := (ymin+ymax)/2;
2782 FOR seg IN 1..4 LOOP
2785 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2788 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2791 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2794 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2797 IF st_intersects(geometry, secbox) THEN
2798 secgeo := st_intersection(geometry, secbox);
2799 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2800 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2801 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2803 RETURN NEXT geo.geom;
2815 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2816 RETURNS SETOF GEOMETRY
2821 -- 10000000000 is ~~ 1x1 degree
2822 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2823 RETURN NEXT geo.geom;
2831 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2835 osmtype character(1);
2839 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2840 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2841 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2842 -- force delete from place/placex by making it a very small geometry
2843 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;
2844 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2851 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2859 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2860 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2861 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2862 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2863 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2864 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2865 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'));
2866 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2867 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'));
2873 ELSEIF rank < 18 THEN
2875 ELSEIF rank < 20 THEN
2877 ELSEIF rank = 21 THEN
2879 ELSEIF rank < 24 THEN
2881 ELSEIF rank < 26 THEN
2882 diameter := 0.002; -- 100 to 200 meters
2883 ELSEIF rank < 28 THEN
2884 diameter := 0.001; -- 50 to 100 meters
2886 IF diameter > 0 THEN
2888 -- roads may cause reparenting for >27 rank places
2889 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2890 ELSEIF rank >= 16 THEN
2891 -- up to rank 16, street-less addresses may need reparenting
2892 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');
2894 -- for all other places the search terms may change as well
2895 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);