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 = 'boundary' AND NEW.type = 'administrative'
857 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
859 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
861 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
862 NEW.rank_search = 30;
863 NEW.rank_address = 0;
864 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
865 NEW.rank_search = 30;
866 NEW.rank_address = 0;
868 -- do table lookup stuff
869 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
870 classtype = NEW.type || NEW.admin_level::TEXT;
872 classtype = NEW.type;
874 SELECT l.rank_search, l.rank_address FROM address_levels l
875 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
876 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
877 ORDER BY l.country_code, l.class, l.type LIMIT 1
878 INTO NEW.rank_search, NEW.rank_address;
880 IF NEW.rank_search is NULL THEN
881 NEW.rank_search := 30;
884 IF NEW.rank_address is NULL THEN
885 NEW.rank_address := 30;
889 -- some postcorrections
890 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
891 -- Slightly promote waterway relations so that they are processed
892 -- before their members.
893 NEW.rank_search := NEW.rank_search - 1;
896 IF (NEW.extratags -> 'capital') = 'yes' THEN
897 NEW.rank_search := NEW.rank_search - 1;
902 -- a country code make no sense below rank 4 (country)
903 IF NEW.rank_search < 4 THEN
904 NEW.country_code := NULL;
907 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
909 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
911 IF NEW.rank_address > 0 THEN
912 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
913 -- Performance: We just can't handle re-indexing for country level changes
914 IF st_area(NEW.geometry) < 1 THEN
915 -- mark items within the geometry for re-indexing
916 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
918 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
919 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
920 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'));
921 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
922 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'));
925 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
927 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
928 IF NEW.type='postcode' THEN
930 ELSEIF NEW.rank_search < 16 THEN
932 ELSEIF NEW.rank_search < 18 THEN
934 ELSEIF NEW.rank_search < 20 THEN
936 ELSEIF NEW.rank_search = 21 THEN
938 ELSEIF NEW.rank_search < 24 THEN
940 ELSEIF NEW.rank_search < 26 THEN
941 diameter := 0.002; -- 100 to 200 meters
942 ELSEIF NEW.rank_search < 28 THEN
943 diameter := 0.001; -- 50 to 100 meters
946 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
947 IF NEW.rank_search >= 26 THEN
948 -- roads may cause reparenting for >27 rank places
949 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
950 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
951 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
952 ELSEIF NEW.rank_search >= 16 THEN
953 -- up to rank 16, street-less addresses may need reparenting
954 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');
956 -- for all other places the search terms may change as well
957 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);
964 -- add to tables for special search
965 -- Note: won't work on initial import because the classtype tables
966 -- do not yet exist. It won't hurt either.
967 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
968 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
970 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
971 USING NEW.place_id, ST_Centroid(NEW.geometry);
980 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
984 place_centroid GEOMETRY;
994 interpol_postcode TEXT;
998 IF OLD.indexed_status = 100 THEN
999 delete from location_property_osmline where place_id = OLD.place_id;
1003 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1007 NEW.interpolationtype = NEW.address->'interpolation';
1009 place_centroid := ST_PointOnSurface(NEW.linegeo);
1010 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1011 NEW.address->'place',
1012 NEW.partition, place_centroid, NEW.linegeo);
1014 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1015 interpol_postcode := NEW.address->'postcode';
1016 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1018 interpol_postcode := NULL;
1021 -- if the line was newly inserted, split the line as necessary
1022 IF OLD.indexed_status = 1 THEN
1023 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1025 IF array_upper(waynodes, 1) IS NULL THEN
1029 linegeo := NEW.linegeo;
1030 startnumber := NULL;
1032 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1034 select osm_id, address, geometry
1035 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1036 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1037 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1038 IF nextnode.osm_id IS NOT NULL THEN
1039 --RAISE NOTICE 'place_id is not null';
1040 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1041 -- Make sure that the point is actually on the line. That might
1042 -- be a bit paranoid but ensures that the algorithm still works
1043 -- should osm2pgsql attempt to repair geometries.
1044 splitline := split_line_on_node(linegeo, nextnode.geometry);
1045 sectiongeo := ST_GeometryN(splitline, 1);
1046 linegeo := ST_GeometryN(splitline, 2);
1048 sectiongeo = linegeo;
1050 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1052 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1053 AND startnumber != endnumber
1054 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1056 IF (startnumber > endnumber) THEN
1057 housenum := endnumber;
1058 endnumber := startnumber;
1059 startnumber := housenum;
1060 sectiongeo := ST_Reverse(sectiongeo);
1063 -- determine postcode
1064 postcode := coalesce(interpol_postcode,
1065 prevnode.address->'postcode',
1066 nextnode.address->'postcode',
1069 IF postcode is NULL THEN
1070 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1072 IF postcode is NULL THEN
1073 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1076 IF NEW.startnumber IS NULL THEN
1077 NEW.startnumber := startnumber;
1078 NEW.endnumber := endnumber;
1079 NEW.linegeo := sectiongeo;
1080 NEW.postcode := upper(trim(postcode));
1082 insert into location_property_osmline
1083 (linegeo, partition, osm_id, parent_place_id,
1084 startnumber, endnumber, interpolationtype,
1085 address, postcode, country_code,
1086 geometry_sector, indexed_status)
1087 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1088 startnumber, endnumber, NEW.interpolationtype,
1089 NEW.address, postcode,
1090 NEW.country_code, NEW.geometry_sector, 0);
1094 -- early break if we are out of line string,
1095 -- might happen when a line string loops back on itself
1096 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1100 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1101 prevnode := nextnode;
1106 -- marking descendants for reparenting is not needed, because there are
1107 -- actually no descendants for interpolation lines
1113 -- Trigger for updates of location_postcode
1115 -- Computes the parent object the postcode most likely refers to.
1116 -- This will be the place that determines the address displayed when
1117 -- searching for this postcode.
1118 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1125 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1129 NEW.indexed_date = now();
1131 partition := get_partition(NEW.country_code);
1133 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1134 INTO NEW.rank_search, NEW.rank_address;
1136 NEW.parent_place_id = 0;
1139 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1140 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1142 NEW.parent_place_id = location.place_id;
1150 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1155 place_centroid GEOMETRY;
1156 near_centroid GEOMETRY;
1158 search_maxdistance FLOAT[];
1159 search_mindistance FLOAT[];
1160 address_havelevel BOOLEAN[];
1167 relation_members TEXT[];
1169 linkedplacex RECORD;
1171 search_diameter FLOAT;
1172 search_prevdiameter FLOAT;
1173 search_maxrank INTEGER;
1174 address_maxrank INTEGER;
1175 address_street_word_id INTEGER;
1176 address_street_word_ids INTEGER[];
1177 parent_place_id_rank BIGINT;
1185 location_rank_search INTEGER;
1186 location_distance FLOAT;
1187 location_parent GEOMETRY;
1188 location_isaddress BOOLEAN;
1189 location_keywords INTEGER[];
1191 default_language TEXT;
1192 name_vector INTEGER[];
1193 nameaddress_vector INTEGER[];
1195 linked_node_id BIGINT;
1196 linked_importance FLOAT;
1197 linked_wikipedia TEXT;
1202 IF OLD.indexed_status = 100 THEN
1203 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1204 delete from placex where place_id = OLD.place_id;
1208 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1212 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1214 NEW.indexed_date = now();
1216 IF NOT %REVERSE-ONLY% THEN
1217 DELETE from search_name WHERE place_id = NEW.place_id;
1219 result := deleteSearchName(NEW.partition, NEW.place_id);
1220 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1221 result := deleteRoad(NEW.partition, NEW.place_id);
1222 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1223 UPDATE placex set linked_place_id = null, indexed_status = 2
1224 where linked_place_id = NEW.place_id;
1225 -- update not necessary for osmline, cause linked_place_id does not exist
1227 IF NEW.linked_place_id is not null THEN
1228 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1232 --DEBUG: RAISE WARNING 'Copy over address tags';
1233 IF NEW.address is not NULL THEN
1234 IF NEW.address ? 'conscriptionnumber' THEN
1235 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1236 IF NEW.address ? 'streetnumber' THEN
1237 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1238 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1240 NEW.housenumber := NEW.address->'conscriptionnumber';
1242 ELSEIF NEW.address ? 'streetnumber' THEN
1243 NEW.housenumber := NEW.address->'streetnumber';
1244 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1245 ELSEIF NEW.address ? 'housenumber' THEN
1246 NEW.housenumber := NEW.address->'housenumber';
1247 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1250 addr_street := NEW.address->'street';
1251 addr_place := NEW.address->'place';
1253 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1254 i := getorcreate_postcode_id(NEW.address->'postcode');
1258 -- Speed up searches - just use the centroid of the feature
1259 -- cheaper but less acurate
1260 place_centroid := ST_PointOnSurface(NEW.geometry);
1261 -- For searching near features rather use the centroid
1262 near_centroid := ST_Centroid(NEW.geometry);
1263 NEW.centroid := null;
1264 NEW.postcode := null;
1265 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1267 -- recalculate country and partition
1268 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1269 -- for countries, believe the mapped country code,
1270 -- so that we remain in the right partition if the boundaries
1272 NEW.country_code := lower(NEW.address->'country');
1273 NEW.partition := get_partition(lower(NEW.country_code));
1274 IF NEW.partition = 0 THEN
1275 NEW.country_code := lower(get_country_code(place_centroid));
1276 NEW.partition := get_partition(NEW.country_code);
1279 IF NEW.rank_search >= 4 THEN
1280 NEW.country_code := lower(get_country_code(place_centroid));
1282 NEW.country_code := NULL;
1284 NEW.partition := get_partition(NEW.country_code);
1286 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1288 -- waterway ways are linked when they are part of a relation and have the same class/type
1289 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1290 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1292 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1293 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1294 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1295 FOR linked_node_id IN SELECT place_id FROM placex
1296 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1297 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1298 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1300 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1305 --DEBUG: RAISE WARNING 'Waterway processed';
1308 -- What level are we searching from
1309 search_maxrank := NEW.rank_search;
1311 -- Thought this wasn't needed but when we add new languages to the country_name table
1312 -- we need to update the existing names
1313 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1314 default_language := get_country_language_code(NEW.country_code);
1315 IF default_language IS NOT NULL THEN
1316 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1317 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1318 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1319 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1323 --DEBUG: RAISE WARNING 'Local names updated';
1325 -- Initialise the name vector using our name
1326 name_vector := make_keywords(NEW.name);
1327 nameaddress_vector := '{}'::int[];
1330 address_havelevel[i] := false;
1333 NEW.importance := null;
1334 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1335 IF NEW.importance IS NULL THEN
1336 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;
1339 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1341 -- ---------------------------------------------------------------------------
1342 -- For low level elements we inherit from our parent road
1343 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1345 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1347 -- We won't get a better centroid, besides these places are too small to care
1348 NEW.centroid := place_centroid;
1350 NEW.parent_place_id := null;
1352 -- if we have a POI and there is no address information,
1353 -- see if we can get it from a surrounding building
1354 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1355 AND NEW.housenumber IS NULL THEN
1356 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1357 and address is not null
1358 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1359 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1362 NEW.housenumber := location.address->'housenumber';
1363 addr_street := location.address->'street';
1364 addr_place := location.address->'place';
1365 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1369 -- We have to find our parent road.
1370 -- Copy data from linked items (points on ways, addr:street links, relations)
1372 -- Is this object part of a relation?
1373 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1375 -- At the moment we only process one type of relation - associatedStreet
1376 IF relation.tags @> ARRAY['associatedStreet'] THEN
1377 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1378 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1379 --RAISE WARNING 'node in relation %',relation;
1380 SELECT place_id from placex where osm_type = 'W'
1381 and osm_id = substring(relation.members[i],2,200)::bigint
1382 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1387 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1389 -- Note that addr:street links can only be indexed once the street itself is indexed
1390 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1391 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1392 IF address_street_word_ids IS NOT NULL THEN
1393 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1396 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1398 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1399 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1400 IF address_street_word_ids IS NOT NULL THEN
1401 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1404 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1406 -- Is this node part of an interpolation?
1407 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1408 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1409 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1410 LIMIT 1 INTO NEW.parent_place_id;
1412 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1414 -- Is this node part of a way?
1415 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1418 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1419 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)
1421 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1423 -- Way IS a road then we are on it - that must be our road
1424 IF location.rank_search < 28 THEN
1425 --RAISE WARNING 'node in way that is a street %',location;
1426 NEW.parent_place_id := location.place_id;
1429 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1431 -- If the way mentions a street or place address, try that for parenting.
1432 IF location.address is not null THEN
1433 IF location.address ? 'street' THEN
1434 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1435 IF address_street_word_ids IS NOT NULL THEN
1436 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1437 EXIT WHEN NEW.parent_place_id is not NULL;
1440 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1442 IF location.address ? 'place' THEN
1443 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1444 IF address_street_word_ids IS NOT NULL THEN
1445 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1446 EXIT WHEN NEW.parent_place_id is not NULL;
1449 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1452 -- Is the WAY part of a relation
1453 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1455 -- At the moment we only process one type of relation - associatedStreet
1456 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1457 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1458 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1459 --RAISE WARNING 'node in way that is in a relation %',relation;
1460 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1461 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1466 EXIT WHEN NEW.parent_place_id is not null;
1467 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1472 -- Still nothing, just use the nearest road
1473 IF NEW.parent_place_id IS NULL THEN
1474 SELECT place_id FROM getNearestRoadFeature(NEW.partition, near_centroid) INTO NEW.parent_place_id;
1476 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1479 -- If we didn't find any road fallback to standard method
1480 IF NEW.parent_place_id IS NOT NULL THEN
1482 -- Get the details of the parent road
1483 SELECT p.country_code, p.postcode FROM placex p
1484 WHERE p.place_id = NEW.parent_place_id INTO location;
1486 NEW.country_code := location.country_code;
1487 --DEBUG: RAISE WARNING 'Got parent details from search name';
1489 -- determine postcode
1490 IF NEW.rank_search > 4 THEN
1491 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1492 NEW.postcode = upper(trim(NEW.address->'postcode'));
1494 NEW.postcode := location.postcode;
1496 IF NEW.postcode is null THEN
1497 NEW.postcode := get_nearest_postcode(NEW.country_code, near_centroid);
1501 -- If there is no name it isn't searchable, don't bother to create a search record
1502 IF NEW.name is NULL THEN
1503 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1507 -- Performance, it would be more acurate to do all the rest of the import
1508 -- process but it takes too long
1509 -- Just be happy with inheriting from parent road only
1510 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1511 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);
1512 --DEBUG: RAISE WARNING 'Place added to location table';
1515 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1516 NEW.rank_search, NEW.rank_address, NEW.geometry);
1518 IF NOT %REVERSE-ONLY% THEN
1519 -- Merge address from parent
1520 SELECT s.name_vector, s.nameaddress_vector FROM search_name s
1521 WHERE s.place_id = NEW.parent_place_id INTO location;
1523 nameaddress_vector := array_merge(nameaddress_vector,
1524 location.nameaddress_vector);
1525 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1527 INSERT INTO search_name (place_id, search_rank, address_rank,
1528 importance, country_code, name_vector,
1529 nameaddress_vector, centroid)
1530 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1531 NEW.importance, NEW.country_code, name_vector,
1532 nameaddress_vector, place_centroid);
1533 --DEBUG: RAISE WARNING 'Place added to search table';
1541 -- ---------------------------------------------------------------------------
1543 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1545 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1547 -- see if we have any special relation members
1548 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1549 --DEBUG: RAISE WARNING 'Got relation members';
1551 IF relation_members IS NOT NULL THEN
1552 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1553 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1555 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1556 and osm_id = substring(relMember.member,2,10000)::bigint
1557 and class = 'place' order by rank_search desc limit 1 LOOP
1559 -- If we don't already have one use this as the centre point of the geometry
1560 IF NEW.centroid IS NULL THEN
1561 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1564 -- merge in the label name, re-init word vector
1565 IF NOT linkedPlacex.name IS NULL THEN
1566 NEW.name := linkedPlacex.name || NEW.name;
1567 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1570 -- merge in extra tags
1571 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1573 -- mark the linked place (excludes from search results)
1574 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1576 -- keep a note of the node id in case we need it for wikipedia in a bit
1577 linked_node_id := linkedPlacex.osm_id;
1578 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1579 --DEBUG: RAISE WARNING 'Linked label member';
1584 IF NEW.centroid IS NULL THEN
1586 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1587 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1589 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1590 and osm_id = substring(relMember.member,2,10000)::bigint
1591 and class = 'place' order by rank_search desc limit 1 LOOP
1593 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1594 -- But that can be fixed by explicitly setting the label in the data
1595 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1596 AND NEW.rank_address = linkedPlacex.rank_address THEN
1598 -- If we don't already have one use this as the centre point of the geometry
1599 IF NEW.centroid IS NULL THEN
1600 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1603 -- merge in the name, re-init word vector
1604 IF NOT linkedPlacex.name IS NULL THEN
1605 NEW.name := linkedPlacex.name || NEW.name;
1606 name_vector := make_keywords(NEW.name);
1609 -- merge in extra tags
1610 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1612 -- mark the linked place (excludes from search results)
1613 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1615 -- keep a note of the node id in case we need it for wikipedia in a bit
1616 linked_node_id := linkedPlacex.osm_id;
1617 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1618 --DEBUG: RAISE WARNING 'Linked admin_center';
1630 -- Name searches can be done for ways as well as relations
1631 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1633 -- not found one yet? how about doing a name search
1634 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1636 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1637 FOR linkedPlacex IN select placex.* from placex WHERE
1638 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1639 AND placex.rank_address = NEW.rank_address
1640 AND placex.place_id != NEW.place_id
1641 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1642 AND st_covers(NEW.geometry, placex.geometry)
1644 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1645 -- If we don't already have one use this as the centre point of the geometry
1646 IF NEW.centroid IS NULL THEN
1647 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1650 -- merge in the name, re-init word vector
1651 NEW.name := linkedPlacex.name || NEW.name;
1652 name_vector := make_keywords(NEW.name);
1654 -- merge in extra tags
1655 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1657 -- mark the linked place (excludes from search results)
1658 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1660 -- keep a note of the node id in case we need it for wikipedia in a bit
1661 linked_node_id := linkedPlacex.osm_id;
1662 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1663 --DEBUG: RAISE WARNING 'Linked named place';
1667 IF NEW.centroid IS NOT NULL THEN
1668 place_centroid := NEW.centroid;
1669 -- Place might have had only a name tag before but has now received translations
1670 -- from the linked place. Make sure a name tag for the default language exists in
1672 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1673 default_language := get_country_language_code(NEW.country_code);
1674 IF default_language IS NOT NULL THEN
1675 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1676 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1677 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1678 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1682 --DEBUG: RAISE WARNING 'Names updated from linked places';
1685 -- Use the maximum importance if a one could be computed from the linked object.
1686 IF linked_importance is not null AND
1687 (NEW.importance is null or NEW.importance < linked_importance) THEN
1688 NEW.importance = linked_importance;
1691 -- Still null? how about looking it up by the node id
1692 IF NEW.importance IS NULL THEN
1693 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1694 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;
1699 -- make sure all names are in the word table
1700 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
1701 perform create_country(NEW.name, lower(NEW.country_code));
1702 --DEBUG: RAISE WARNING 'Country names updated';
1705 NEW.parent_place_id = 0;
1706 parent_place_id_rank = 0;
1709 -- convert address store to array of tokenids
1710 --DEBUG: RAISE WARNING 'Starting address search';
1711 isin_tokens := '{}'::int[];
1712 IF NEW.address IS NOT NULL THEN
1713 FOR addr_item IN SELECT * FROM each(NEW.address)
1715 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1716 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1717 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1718 isin_tokens := isin_tokens || address_street_word_id;
1720 IF NOT %REVERSE-ONLY% THEN
1721 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1722 IF address_street_word_id IS NOT NULL THEN
1723 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1727 IF addr_item.key = 'is_in' THEN
1728 -- is_in items need splitting
1729 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1730 IF array_upper(isin, 1) IS NOT NULL THEN
1731 FOR i IN 1..array_upper(isin, 1) LOOP
1732 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1733 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1734 isin_tokens := isin_tokens || address_street_word_id;
1737 -- merge word into address vector
1738 IF NOT %REVERSE-ONLY% THEN
1739 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1740 IF address_street_word_id IS NOT NULL THEN
1741 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1749 IF NOT %REVERSE-ONLY% THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1753 -- RAISE WARNING 'ISIN: %', isin_tokens;
1755 -- Process area matches
1756 location_rank_search := 0;
1757 location_distance := 0;
1758 location_parent := NULL;
1759 -- added ourself as address already
1760 address_havelevel[NEW.rank_address] := true;
1761 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1763 SELECT * from getNearFeatures(NEW.partition,
1764 CASE WHEN NEW.rank_search >= 26
1765 AND NEW.rank_search < 30
1767 ELSE near_centroid END,
1768 search_maxrank, isin_tokens)
1770 IF location.rank_address != location_rank_search THEN
1771 location_rank_search := location.rank_address;
1772 IF location.isguess THEN
1773 location_distance := location.distance * 1.5;
1775 IF location.rank_address <= 12 THEN
1776 -- for county and above, if we have an area consider that exact
1777 -- (It would be nice to relax the constraint for places close to
1778 -- the boundary but we'd need the exact geometry for that. Too
1780 location_distance = 0;
1782 -- Below county level remain slightly fuzzy.
1783 location_distance := location.distance * 0.5;
1787 CONTINUE WHEN location.keywords <@ location_keywords;
1790 IF location.distance < location_distance OR NOT location.isguess THEN
1791 location_keywords := location.keywords;
1793 location_isaddress := NOT address_havelevel[location.rank_address];
1794 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1795 location_isaddress := ST_Contains(location_parent,location.centroid);
1798 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1799 -- Add it to the list of search terms
1800 IF NOT %REVERSE-ONLY% AND location.rank_search > 4 THEN
1801 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1803 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1804 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1806 IF location_isaddress THEN
1807 -- add postcode if we have one
1808 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1809 IF location.postcode is not null THEN
1810 NEW.postcode = location.postcode;
1813 address_havelevel[location.rank_address] := true;
1814 IF NOT location.isguess THEN
1815 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1818 IF location.rank_address > parent_place_id_rank THEN
1819 NEW.parent_place_id = location.place_id;
1820 parent_place_id_rank = location.rank_address;
1825 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1830 --DEBUG: RAISE WARNING 'address computed';
1832 IF NEW.address is not null AND NEW.address ? 'postcode'
1833 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1834 NEW.postcode := upper(trim(NEW.address->'postcode'));
1837 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1838 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1841 -- if we have a name add this to the name search table
1842 IF NEW.name IS NOT NULL THEN
1844 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1845 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);
1846 --DEBUG: RAISE WARNING 'added to location (full)';
1849 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1850 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1851 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1854 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1855 NEW.rank_search, NEW.rank_address, NEW.geometry);
1856 --DEBUG: RAISE WARNING 'added to search name (full)';
1858 IF NOT %REVERSE-ONLY% THEN
1859 INSERT INTO search_name (place_id, search_rank, address_rank,
1860 importance, country_code, name_vector,
1861 nameaddress_vector, centroid)
1862 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1863 NEW.importance, NEW.country_code, name_vector,
1864 nameaddress_vector, place_centroid);
1869 -- If we've not managed to pick up a better one - default centroid
1870 IF NEW.centroid IS NULL THEN
1871 NEW.centroid := place_centroid;
1874 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1881 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1887 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1889 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1890 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1891 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1892 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1894 IF OLD.rank_address < 30 THEN
1896 -- mark everything linked to this place for re-indexing
1897 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1898 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1899 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1901 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1902 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1904 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1905 b := deleteRoad(OLD.partition, OLD.place_id);
1907 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1908 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1909 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1910 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1911 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1915 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1917 IF OLD.rank_address < 26 THEN
1918 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1921 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1923 IF OLD.name is not null THEN
1924 IF NOT %REVERSE-ONLY% THEN
1925 DELETE from search_name WHERE place_id = OLD.place_id;
1927 b := deleteSearchName(OLD.partition, OLD.place_id);
1930 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1932 DELETE FROM place_addressline where place_id = OLD.place_id;
1934 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1936 -- remove from tables for special search
1937 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1938 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1940 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1943 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1951 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1957 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1959 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1960 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1961 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;
1963 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1969 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;
1971 -- interpolations are special
1972 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1973 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1982 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1987 existingplacex RECORD;
1988 existingline RECORD;
1989 existinggeometry GEOMETRY;
1990 existingplace_id BIGINT;
1995 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
1996 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1997 -- filter wrong tupels
1998 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
1999 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2000 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2001 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2005 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2006 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2007 -- Have we already done this place?
2008 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;
2010 -- Get the existing place_id
2011 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2013 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2014 IF existing.osm_type IS NULL THEN
2015 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2018 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2019 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2021 -- 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)
2022 IF existingline.osm_id IS NOT NULL THEN
2023 delete from location_property_osmline where osm_id = NEW.osm_id;
2026 -- for interpolations invalidate all nodes on the line
2027 update placex p set indexed_status = 2
2028 from planet_osm_ways w
2029 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2032 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2033 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2036 IF existing.osm_type IS NULL THEN
2040 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2041 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2042 OR existing.geometry::text != NEW.geometry::text
2047 address = NEW.address,
2048 extratags = NEW.extratags,
2049 admin_level = NEW.admin_level,
2050 geometry = NEW.geometry
2051 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2056 ELSE -- insert to placex
2058 -- Patch in additional country names
2059 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2060 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2061 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2062 IF existing.name IS NOT NULL THEN
2063 NEW.name = existing.name || NEW.name;
2067 -- Have we already done this place?
2068 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;
2070 -- Get the existing place_id
2071 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;
2073 -- Handle a place changing type by removing the old data
2074 -- My generated 'place' types are causing havok because they overlap with real keys
2075 -- TODO: move them to their own special purpose key/class to avoid collisions
2076 IF existing.osm_type IS NULL THEN
2077 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2080 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2081 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2084 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2085 AND st_area(existing.geometry) > 0.02
2086 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2087 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2089 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2090 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2091 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2095 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2096 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2098 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2099 IF existingplacex.osm_type IS NULL OR
2100 (existingplacex.class = 'boundary' AND
2101 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2102 (existingplacex.type != NEW.type)))
2105 IF existingplacex.osm_type IS NOT NULL THEN
2106 -- sanity check: ignore admin_level changes on places with too many active children
2107 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2108 --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;
2109 --LIMIT INDEXING: IF i > 100000 THEN
2110 --LIMIT INDEXING: RETURN null;
2111 --LIMIT INDEXING: END IF;
2114 IF existing.osm_type IS NOT NULL THEN
2115 -- pathological case caused by the triggerless copy into place during initial import
2116 -- force delete even for large areas, it will be reinserted later
2117 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;
2118 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2121 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2122 insert into placex (osm_type, osm_id, class, type, name,
2123 admin_level, address, extratags, geometry)
2124 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2125 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2127 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2132 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2133 IF existing.geometry::text != NEW.geometry::text
2134 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2135 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2138 -- Get the version of the geometry actually used (in placex table)
2139 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;
2141 -- Performance limit
2142 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2144 -- 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
2145 update placex set indexed_status = 2 where indexed_status = 0 and
2146 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2147 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2148 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2150 update placex set indexed_status = 2 where indexed_status = 0 and
2151 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2152 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2153 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2160 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2161 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2162 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2163 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2164 OR existing.geometry::text != NEW.geometry::text
2169 address = NEW.address,
2170 extratags = NEW.extratags,
2171 admin_level = NEW.admin_level,
2172 geometry = NEW.geometry
2173 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2176 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2177 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2178 -- postcode was deleted, no longer retain in placex
2179 DELETE FROM placex where place_id = existingplacex.place_id;
2183 NEW.name := hstore('ref', NEW.address->'postcode');
2186 IF NEW.class in ('boundary')
2187 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2188 DELETE FROM placex where place_id = existingplacex.place_id;
2194 address = NEW.address,
2195 parent_place_id = null,
2196 extratags = NEW.extratags,
2197 admin_level = NEW.admin_level,
2199 geometry = NEW.geometry
2200 where place_id = existingplacex.place_id;
2202 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2203 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2204 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2205 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2206 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);
2209 -- linked places should get potential new naming and addresses
2210 IF existingplacex.linked_place_id is not NULL THEN
2213 extratags = p.extratags,
2216 where x.place_id = existingplacex.linked_place_id
2217 and x.indexed_status = 0
2218 and x.osm_type = p.osm_type
2219 and x.osm_id = p.osm_id
2220 and x.class = p.class;
2225 -- Abort the add (we modified the existing place instead)
2230 $$ LANGUAGE plpgsql;
2233 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2238 IF name is null THEN
2242 FOR j IN 1..array_upper(languagepref,1) LOOP
2243 IF name ? languagepref[j] THEN
2244 result := trim(name->languagepref[j]);
2245 IF result != '' THEN
2251 -- anything will do as a fallback - just take the first name type thing there is
2252 RETURN trim((avals(name))[1]);
2255 LANGUAGE plpgsql IMMUTABLE;
2257 --housenumber only needed for tiger data
2258 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2270 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2271 currresult := trim(get_name_by_language(location.name, languagepref));
2272 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2273 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2274 prevresult := currresult;
2278 RETURN array_to_string(result,', ');
2283 DROP TYPE IF EXISTS addressline CASCADE;
2284 create type addressline as (
2291 admin_level INTEGER,
2294 rank_address INTEGER,
2298 -- Compute the list of address parts for the given place.
2300 -- If in_housenumber is greator or equal 0, look for an interpolation.
2301 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2304 for_place_id BIGINT;
2309 countrylocation RECORD;
2310 searchcountrycode varchar(2);
2311 searchhousenumber TEXT;
2312 searchhousename HSTORE;
2313 searchrankaddress INTEGER;
2314 searchpostcode TEXT;
2315 postcode_isaddress BOOL;
2320 -- The place ein question might not have a direct entry in place_addressline.
2321 -- Look for the parent of such places then and save if in for_place_id.
2323 postcode_isaddress := true;
2325 -- first query osmline (interpolation lines)
2326 IF in_housenumber >= 0 THEN
2327 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
2328 null, 'place', 'house'
2329 FROM location_property_osmline
2330 WHERE place_id = in_place_id AND in_housenumber>=startnumber
2331 AND in_housenumber <= endnumber
2332 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2333 searchpostcode, searchhousename, searchclass, searchtype;
2336 --then query tiger data
2337 -- %NOTIGERDATA% IF 0 THEN
2338 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
2339 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
2341 FROM location_property_tiger
2342 WHERE place_id = in_place_id AND in_housenumber >= startnumber
2343 AND in_housenumber <= endnumber
2344 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2345 searchpostcode, searchhousename, searchclass, searchtype;
2347 -- %NOTIGERDATA% END IF;
2349 -- %NOAUXDATA% IF 0 THEN
2350 IF for_place_id IS NULL THEN
2351 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
2352 FROM location_property_aux
2353 WHERE place_id = in_place_id
2354 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
2355 searchpostcode, searchhousename, searchclass, searchtype;
2357 -- %NOAUXDATA% END IF;
2360 IF for_place_id IS NULL THEN
2361 SELECT parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2362 FROM location_postcode
2363 WHERE place_id = in_place_id
2364 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
2365 searchclass, searchtype;
2368 -- POI objects in the placex table
2369 IF for_place_id IS NULL THEN
2370 SELECT parent_place_id, country_code, housenumber, rank_search, postcode,
2373 WHERE place_id = in_place_id and rank_search > 27
2374 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2375 searchpostcode, searchhousename, searchclass, searchtype;
2378 -- If for_place_id is still NULL at this point then the object has its own
2379 -- entry in place_address line. However, still check if there is not linked
2380 -- place we should be using instead.
2381 IF for_place_id IS NULL THEN
2382 select coalesce(linked_place_id, place_id), country_code,
2383 housenumber, rank_search, postcode, null
2384 from placex where place_id = in_place_id
2385 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2388 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2390 found := 1000; -- the lowest rank_address included
2392 -- Return the record for the base entry.
2394 SELECT placex.place_id, osm_type, osm_id, name,
2395 class, type, admin_level,
2396 type not in ('postcode', 'postal_code') as isaddress,
2397 CASE WHEN rank_address = 0 THEN 100
2398 WHEN rank_address = 11 THEN 5
2399 ELSE rank_address END as rank_address,
2400 0 as distance, country_code, postcode
2402 WHERE place_id = for_place_id
2404 --RAISE WARNING '%',location;
2405 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2406 searchcountrycode := location.country_code;
2408 IF location.rank_address < 4 THEN
2409 -- no country locations for ranks higher than country
2410 searchcountrycode := NULL;
2412 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2413 location.name, location.class, location.type,
2414 location.admin_level, true, location.isaddress,
2415 location.rank_address, location.distance)::addressline;
2416 RETURN NEXT countrylocation;
2417 found := location.rank_address;
2421 SELECT placex.place_id, osm_type, osm_id, name,
2422 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2423 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2424 admin_level, fromarea, isaddress,
2425 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2426 distance, country_code, postcode
2427 FROM place_addressline join placex on (address_place_id = placex.place_id)
2428 WHERE place_addressline.place_id = for_place_id
2429 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
2430 AND linked_place_id is null
2431 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
2432 OR placex.country_code = searchcountrycode)
2433 ORDER BY rank_address desc, isaddress desc, fromarea desc,
2434 distance asc, rank_search desc
2436 --RAISE WARNING '%',location;
2437 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2438 searchcountrycode := location.country_code;
2440 IF location.type in ('postcode', 'postal_code') THEN
2441 postcode_isaddress := false;
2442 IF location.osm_type != 'R' THEN
2443 location.isaddress := FALSE;
2446 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2447 location.name, location.class, location.type,
2448 location.admin_level, location.fromarea,
2449 location.isaddress, location.rank_address,
2450 location.distance)::addressline;
2451 RETURN NEXT countrylocation;
2452 found := location.rank_address;
2455 -- If no country was included yet, add the name information from country_name.
2457 SELECT name FROM country_name
2458 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
2459 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2460 IF countryname IS NOT NULL THEN
2461 location := ROW(null, null, null, countryname, 'place', 'country',
2462 null, true, true, 4, 0)::addressline;
2463 RETURN NEXT location;
2467 -- Finally add some artificial rows.
2468 IF searchcountrycode IS NOT NULL THEN
2469 location := ROW(null, null, null, hstore('ref', searchcountrycode),
2470 'place', 'country_code', null, true, false, 4, 0)::addressline;
2471 RETURN NEXT location;
2474 IF searchhousename IS NOT NULL THEN
2475 location := ROW(in_place_id, null, null, searchhousename, searchclass,
2476 searchtype, null, true, true, 29, 0)::addressline;
2477 RETURN NEXT location;
2480 IF searchhousenumber IS NOT NULL THEN
2481 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber),
2482 'place', 'house_number', null, true, true, 28, 0)::addressline;
2483 RETURN NEXT location;
2486 IF searchpostcode IS NOT NULL THEN
2487 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
2488 'postcode', null, false, postcode_isaddress, 5, 0)::addressline;
2489 RETURN NEXT location;
2498 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2499 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2504 place_centroid GEOMETRY;
2505 out_partition INTEGER;
2506 out_parent_place_id BIGINT;
2508 address_street_word_id INTEGER;
2513 place_centroid := ST_Centroid(pointgeo);
2514 out_partition := get_partition(in_countrycode);
2515 out_parent_place_id := null;
2517 address_street_word_id := get_name_id(make_standard_name(in_street));
2518 IF address_street_word_id IS NOT NULL THEN
2519 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2520 out_parent_place_id := location.place_id;
2524 IF out_parent_place_id IS NULL THEN
2525 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2526 out_parent_place_id := location.place_id;
2530 out_postcode := in_postcode;
2531 IF out_postcode IS NULL THEN
2532 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2534 -- XXX look into postcode table
2537 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2538 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2539 newpoints := newpoints + 1;
2546 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2553 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2554 IF members[i+1] = member THEN
2555 result := result || members[i];
2564 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2570 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2571 IF members[i+1] = ANY(memberLabels) THEN
2572 RETURN NEXT members[i];
2581 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2582 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2584 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2585 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
2586 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2587 ), '') AS bytea), 'UTF8');
2589 LANGUAGE SQL IMMUTABLE STRICT;
2591 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2595 RETURN decode_url_part(p);
2597 WHEN others THEN return null;
2600 LANGUAGE plpgsql IMMUTABLE;
2602 DROP TYPE wikipedia_article_match CASCADE;
2603 create type wikipedia_article_match as (
2609 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2615 wiki_article_title TEXT;
2616 wiki_article_language TEXT;
2617 result wikipedia_article_match;
2619 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'];
2621 WHILE langs[i] IS NOT NULL LOOP
2622 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2623 IF wiki_article is not null THEN
2624 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2625 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2626 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2627 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2628 wiki_article := replace(wiki_article,' ','_');
2629 IF strpos(wiki_article, ':') IN (3,4) THEN
2630 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2631 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2633 wiki_article_title := trim(wiki_article);
2634 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;
2637 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2638 from wikipedia_article
2639 where language = wiki_article_language and
2640 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2642 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2643 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2644 where wikipedia_redirect.language = wiki_article_language and
2645 (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'\\',''))
2646 order by importance desc limit 1 INTO result;
2648 IF result.language is not null THEN
2659 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2660 RETURNS SETOF GEOMETRY
2674 remainingdepth INTEGER;
2679 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2681 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2682 RETURN NEXT geometry;
2686 remainingdepth := maxdepth - 1;
2687 area := ST_AREA(geometry);
2688 IF remainingdepth < 1 OR area < maxarea THEN
2689 RETURN NEXT geometry;
2693 xmin := st_xmin(geometry);
2694 xmax := st_xmax(geometry);
2695 ymin := st_ymin(geometry);
2696 ymax := st_ymax(geometry);
2697 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2699 -- if the geometry completely covers the box don't bother to slice any more
2700 IF ST_AREA(secbox) = area THEN
2701 RETURN NEXT geometry;
2705 xmid := (xmin+xmax)/2;
2706 ymid := (ymin+ymax)/2;
2709 FOR seg IN 1..4 LOOP
2712 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2715 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2718 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2721 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2724 IF st_intersects(geometry, secbox) THEN
2725 secgeo := st_intersection(geometry, secbox);
2726 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2727 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2728 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2730 RETURN NEXT geo.geom;
2742 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2743 RETURNS SETOF GEOMETRY
2748 -- 10000000000 is ~~ 1x1 degree
2749 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2750 RETURN NEXT geo.geom;
2758 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2762 osmtype character(1);
2766 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2767 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2768 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2769 -- force delete from place/placex by making it a very small geometry
2770 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;
2771 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2778 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2786 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2787 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2788 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2789 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2790 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2791 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2792 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'));
2793 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2794 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'));
2800 ELSEIF rank < 18 THEN
2802 ELSEIF rank < 20 THEN
2804 ELSEIF rank = 21 THEN
2806 ELSEIF rank < 24 THEN
2808 ELSEIF rank < 26 THEN
2809 diameter := 0.002; -- 100 to 200 meters
2810 ELSEIF rank < 28 THEN
2811 diameter := 0.001; -- 50 to 100 meters
2813 IF diameter > 0 THEN
2815 -- roads may cause reparenting for >27 rank places
2816 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2817 ELSEIF rank >= 16 THEN
2818 -- up to rank 16, street-less addresses may need reparenting
2819 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');
2821 -- for all other places the search terms may change as well
2822 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);