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 = 'place' THEN
891 IF NEW.type in ('continent', 'sea', 'country', 'state') AND NEW.osm_type = 'N' THEN
892 NEW.rank_address := 0;
894 ELSEIF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
895 -- Slightly promote waterway relations so that they are processed
896 -- before their members.
897 NEW.rank_search := NEW.rank_search - 1;
900 IF (NEW.extratags -> 'capital') = 'yes' THEN
901 NEW.rank_search := NEW.rank_search - 1;
906 -- a country code make no sense below rank 4 (country)
907 IF NEW.rank_search < 4 THEN
908 NEW.country_code := NULL;
911 -- Block import below rank 22
912 -- IF NEW.rank_search > 22 THEN
916 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
918 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
920 IF NEW.rank_address > 0 THEN
921 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
922 -- Performance: We just can't handle re-indexing for country level changes
923 IF st_area(NEW.geometry) < 1 THEN
924 -- mark items within the geometry for re-indexing
925 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
927 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
928 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
929 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'));
930 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
931 AND rank_search > NEW.rank_search and indexed_status = 0 and ST_geometrytype(placex.geometry) != 'ST_Point' and (rank_search < 28 or name is not null or (NEW.rank_search >= 16 and address ? 'place'));
934 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
936 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
937 IF NEW.type='postcode' THEN
939 ELSEIF NEW.rank_search < 16 THEN
941 ELSEIF NEW.rank_search < 18 THEN
943 ELSEIF NEW.rank_search < 20 THEN
945 ELSEIF NEW.rank_search = 21 THEN
947 ELSEIF NEW.rank_search < 24 THEN
949 ELSEIF NEW.rank_search < 26 THEN
950 diameter := 0.002; -- 100 to 200 meters
951 ELSEIF NEW.rank_search < 28 THEN
952 diameter := 0.001; -- 50 to 100 meters
955 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
956 IF NEW.rank_search >= 26 THEN
957 -- roads may cause reparenting for >27 rank places
958 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
959 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
960 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
961 ELSEIF NEW.rank_search >= 16 THEN
962 -- up to rank 16, street-less addresses may need reparenting
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 or address ? 'place');
965 -- for all other places the search terms may change as well
966 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);
973 -- add to tables for special search
974 -- Note: won't work on initial import because the classtype tables
975 -- do not yet exist. It won't hurt either.
976 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
977 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
979 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
980 USING NEW.place_id, ST_Centroid(NEW.geometry);
989 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
993 place_centroid GEOMETRY;
1002 sectiongeo GEOMETRY;
1003 interpol_postcode TEXT;
1007 IF OLD.indexed_status = 100 THEN
1008 delete from location_property_osmline where place_id = OLD.place_id;
1012 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1016 NEW.interpolationtype = NEW.address->'interpolation';
1018 place_centroid := ST_PointOnSurface(NEW.linegeo);
1019 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1020 NEW.address->'place',
1021 NEW.partition, place_centroid, NEW.linegeo);
1023 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1024 interpol_postcode := NEW.address->'postcode';
1025 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1027 interpol_postcode := NULL;
1030 -- if the line was newly inserted, split the line as necessary
1031 IF OLD.indexed_status = 1 THEN
1032 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1034 IF array_upper(waynodes, 1) IS NULL THEN
1038 linegeo := NEW.linegeo;
1039 startnumber := NULL;
1041 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1043 select osm_id, address, geometry
1044 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1045 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1046 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1047 IF nextnode.osm_id IS NOT NULL THEN
1048 --RAISE NOTICE 'place_id is not null';
1049 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1050 -- Make sure that the point is actually on the line. That might
1051 -- be a bit paranoid but ensures that the algorithm still works
1052 -- should osm2pgsql attempt to repair geometries.
1053 splitline := split_line_on_node(linegeo, nextnode.geometry);
1054 sectiongeo := ST_GeometryN(splitline, 1);
1055 linegeo := ST_GeometryN(splitline, 2);
1057 sectiongeo = linegeo;
1059 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1061 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1062 AND startnumber != endnumber
1063 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1065 IF (startnumber > endnumber) THEN
1066 housenum := endnumber;
1067 endnumber := startnumber;
1068 startnumber := housenum;
1069 sectiongeo := ST_Reverse(sectiongeo);
1072 -- determine postcode
1073 postcode := coalesce(interpol_postcode,
1074 prevnode.address->'postcode',
1075 nextnode.address->'postcode',
1078 IF postcode is NULL THEN
1079 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1081 IF postcode is NULL THEN
1082 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1085 IF NEW.startnumber IS NULL THEN
1086 NEW.startnumber := startnumber;
1087 NEW.endnumber := endnumber;
1088 NEW.linegeo := sectiongeo;
1089 NEW.postcode := upper(trim(postcode));
1091 insert into location_property_osmline
1092 (linegeo, partition, osm_id, parent_place_id,
1093 startnumber, endnumber, interpolationtype,
1094 address, postcode, country_code,
1095 geometry_sector, indexed_status)
1096 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1097 startnumber, endnumber, NEW.interpolationtype,
1098 NEW.address, postcode,
1099 NEW.country_code, NEW.geometry_sector, 0);
1103 -- early break if we are out of line string,
1104 -- might happen when a line string loops back on itself
1105 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1109 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1110 prevnode := nextnode;
1115 -- marking descendants for reparenting is not needed, because there are
1116 -- actually no descendants for interpolation lines
1122 -- Trigger for updates of location_postcode
1124 -- Computes the parent object the postcode most likely refers to.
1125 -- This will be the place that determines the address displayed when
1126 -- searching for this postcode.
1127 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1134 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1138 NEW.indexed_date = now();
1140 partition := get_partition(NEW.country_code);
1142 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1143 INTO NEW.rank_search, NEW.rank_address;
1145 NEW.parent_place_id = 0;
1148 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1149 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1151 NEW.parent_place_id = location.place_id;
1159 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1164 place_centroid GEOMETRY;
1165 near_centroid GEOMETRY;
1167 search_maxdistance FLOAT[];
1168 search_mindistance FLOAT[];
1169 address_havelevel BOOLEAN[];
1176 relation_members TEXT[];
1178 linkedplacex RECORD;
1180 search_diameter FLOAT;
1181 search_prevdiameter FLOAT;
1182 search_maxrank INTEGER;
1183 address_maxrank INTEGER;
1184 address_street_word_id INTEGER;
1185 address_street_word_ids INTEGER[];
1186 parent_place_id_rank BIGINT;
1194 location_rank_search INTEGER;
1195 location_distance FLOAT;
1196 location_parent GEOMETRY;
1197 location_isaddress BOOLEAN;
1198 location_keywords INTEGER[];
1200 default_language TEXT;
1201 name_vector INTEGER[];
1202 nameaddress_vector INTEGER[];
1204 linked_node_id BIGINT;
1205 linked_importance FLOAT;
1206 linked_wikipedia TEXT;
1211 IF OLD.indexed_status = 100 THEN
1212 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1213 delete from placex where place_id = OLD.place_id;
1217 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1221 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1223 NEW.indexed_date = now();
1225 IF NOT %REVERSE-ONLY% THEN
1226 DELETE from search_name WHERE place_id = NEW.place_id;
1228 result := deleteSearchName(NEW.partition, NEW.place_id);
1229 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1230 result := deleteRoad(NEW.partition, NEW.place_id);
1231 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1232 UPDATE placex set linked_place_id = null, indexed_status = 2
1233 where linked_place_id = NEW.place_id;
1234 -- update not necessary for osmline, cause linked_place_id does not exist
1236 IF NEW.linked_place_id is not null THEN
1237 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1241 --DEBUG: RAISE WARNING 'Copy over address tags';
1242 IF NEW.address is not NULL THEN
1243 IF NEW.address ? 'conscriptionnumber' THEN
1244 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1245 IF NEW.address ? 'streetnumber' THEN
1246 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1247 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1249 NEW.housenumber := NEW.address->'conscriptionnumber';
1251 ELSEIF NEW.address ? 'streetnumber' THEN
1252 NEW.housenumber := NEW.address->'streetnumber';
1253 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1254 ELSEIF NEW.address ? 'housenumber' THEN
1255 NEW.housenumber := NEW.address->'housenumber';
1256 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1259 addr_street := NEW.address->'street';
1260 addr_place := NEW.address->'place';
1262 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1263 i := getorcreate_postcode_id(NEW.address->'postcode');
1267 -- Speed up searches - just use the centroid of the feature
1268 -- cheaper but less acurate
1269 place_centroid := ST_PointOnSurface(NEW.geometry);
1270 -- For searching near features rather use the centroid
1271 near_centroid := ST_Centroid(NEW.geometry);
1272 NEW.centroid := null;
1273 NEW.postcode := null;
1274 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1276 -- recalculate country and partition
1277 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1278 -- for countries, believe the mapped country code,
1279 -- so that we remain in the right partition if the boundaries
1281 NEW.country_code := lower(NEW.address->'country');
1282 NEW.partition := get_partition(lower(NEW.country_code));
1283 IF NEW.partition = 0 THEN
1284 NEW.country_code := lower(get_country_code(place_centroid));
1285 NEW.partition := get_partition(NEW.country_code);
1288 IF NEW.rank_search >= 4 THEN
1289 NEW.country_code := lower(get_country_code(place_centroid));
1291 NEW.country_code := NULL;
1293 NEW.partition := get_partition(NEW.country_code);
1295 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1297 -- waterway ways are linked when they are part of a relation and have the same class/type
1298 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1299 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1301 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1302 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1303 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1304 FOR linked_node_id IN SELECT place_id FROM placex
1305 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1306 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1307 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1309 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1314 --DEBUG: RAISE WARNING 'Waterway processed';
1317 -- What level are we searching from
1318 search_maxrank := NEW.rank_search;
1320 -- Thought this wasn't needed but when we add new languages to the country_name table
1321 -- we need to update the existing names
1322 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1323 default_language := get_country_language_code(NEW.country_code);
1324 IF default_language IS NOT NULL THEN
1325 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1326 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1327 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1328 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1332 --DEBUG: RAISE WARNING 'Local names updated';
1334 -- Initialise the name vector using our name
1335 name_vector := make_keywords(NEW.name);
1336 nameaddress_vector := '{}'::int[];
1339 address_havelevel[i] := false;
1342 NEW.importance := null;
1343 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1344 IF NEW.importance IS NULL THEN
1345 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;
1348 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1350 -- ---------------------------------------------------------------------------
1351 -- For low level elements we inherit from our parent road
1352 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1354 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1356 -- We won't get a better centroid, besides these places are too small to care
1357 NEW.centroid := place_centroid;
1359 NEW.parent_place_id := null;
1361 -- if we have a POI and there is no address information,
1362 -- see if we can get it from a surrounding building
1363 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1364 AND NEW.housenumber IS NULL THEN
1365 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1366 and address is not null
1367 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1368 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1371 NEW.housenumber := location.address->'housenumber';
1372 addr_street := location.address->'street';
1373 addr_place := location.address->'place';
1374 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1378 -- We have to find our parent road.
1379 -- Copy data from linked items (points on ways, addr:street links, relations)
1381 -- Is this object part of a relation?
1382 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1384 -- At the moment we only process one type of relation - associatedStreet
1385 IF relation.tags @> ARRAY['associatedStreet'] THEN
1386 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1387 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1388 --RAISE WARNING 'node in relation %',relation;
1389 SELECT place_id from placex where osm_type = 'W'
1390 and osm_id = substring(relation.members[i],2,200)::bigint
1391 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1396 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1398 -- Note that addr:street links can only be indexed once the street itself is indexed
1399 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1400 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1401 IF address_street_word_ids IS NOT NULL THEN
1402 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1405 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1407 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1408 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1409 IF address_street_word_ids IS NOT NULL THEN
1410 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1413 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1415 -- Is this node part of an interpolation?
1416 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1417 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1418 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1419 LIMIT 1 INTO NEW.parent_place_id;
1421 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1423 -- Is this node part of a way?
1424 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1427 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1428 WHERE p.osm_type = 'W' and p.rank_search >= 26 and p.geometry && NEW.geometry and w.id = p.osm_id and NEW.osm_id = any(w.nodes)
1430 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1432 -- Way IS a road then we are on it - that must be our road
1433 IF location.rank_search < 28 THEN
1434 --RAISE WARNING 'node in way that is a street %',location;
1435 NEW.parent_place_id := location.place_id;
1438 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1440 -- If the way mentions a street or place address, try that for parenting.
1441 IF location.address is not null THEN
1442 IF location.address ? 'street' THEN
1443 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1444 IF address_street_word_ids IS NOT NULL THEN
1445 SELECT place_id from getNearestNamedRoadFeature(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:street in way (%)', NEW.parent_place_id;
1451 IF location.address ? 'place' THEN
1452 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1453 IF address_street_word_ids IS NOT NULL THEN
1454 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1455 EXIT WHEN NEW.parent_place_id is not NULL;
1458 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1461 -- Is the WAY part of a relation
1462 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1464 -- At the moment we only process one type of relation - associatedStreet
1465 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1466 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1467 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1468 --RAISE WARNING 'node in way that is in a relation %',relation;
1469 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1470 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1475 EXIT WHEN NEW.parent_place_id is not null;
1476 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1481 -- Still nothing, just use the nearest road
1482 IF NEW.parent_place_id IS NULL THEN
1483 SELECT place_id FROM getNearestRoadFeature(NEW.partition, near_centroid) INTO NEW.parent_place_id;
1485 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1488 -- If we didn't find any road fallback to standard method
1489 IF NEW.parent_place_id IS NOT NULL THEN
1491 -- Get the details of the parent road
1492 SELECT p.country_code, p.postcode FROM placex p
1493 WHERE p.place_id = NEW.parent_place_id INTO location;
1495 NEW.country_code := location.country_code;
1496 --DEBUG: RAISE WARNING 'Got parent details from search name';
1498 -- determine postcode
1499 IF NEW.rank_search > 4 THEN
1500 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1501 NEW.postcode = upper(trim(NEW.address->'postcode'));
1503 NEW.postcode := location.postcode;
1505 IF NEW.postcode is null THEN
1506 NEW.postcode := get_nearest_postcode(NEW.country_code, near_centroid);
1510 -- If there is no name it isn't searchable, don't bother to create a search record
1511 IF NEW.name is NULL THEN
1512 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1516 -- Performance, it would be more acurate to do all the rest of the import
1517 -- process but it takes too long
1518 -- Just be happy with inheriting from parent road only
1519 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1520 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);
1521 --DEBUG: RAISE WARNING 'Place added to location table';
1524 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1525 NEW.rank_search, NEW.rank_address, NEW.geometry);
1527 IF NOT %REVERSE-ONLY% THEN
1528 -- Merge address from parent
1529 SELECT s.name_vector, s.nameaddress_vector FROM search_name s
1530 WHERE s.place_id = NEW.parent_place_id INTO location;
1532 nameaddress_vector := array_merge(nameaddress_vector,
1533 location.nameaddress_vector);
1534 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1536 INSERT INTO search_name (place_id, search_rank, address_rank,
1537 importance, country_code, name_vector,
1538 nameaddress_vector, centroid)
1539 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1540 NEW.importance, NEW.country_code, name_vector,
1541 nameaddress_vector, place_centroid);
1542 --DEBUG: RAISE WARNING 'Place added to search table';
1550 -- ---------------------------------------------------------------------------
1552 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1554 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1556 -- see if we have any special relation members
1557 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1558 --DEBUG: RAISE WARNING 'Got relation members';
1560 IF relation_members IS NOT NULL THEN
1561 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1562 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1564 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1565 and osm_id = substring(relMember.member,2,10000)::bigint
1566 and class = 'place' order by rank_search desc limit 1 LOOP
1568 -- If we don't already have one use this as the centre point of the geometry
1569 IF NEW.centroid IS NULL THEN
1570 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1573 -- merge in the label name, re-init word vector
1574 IF NOT linkedPlacex.name IS NULL THEN
1575 NEW.name := linkedPlacex.name || NEW.name;
1576 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1579 -- merge in extra tags
1580 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1582 -- mark the linked place (excludes from search results)
1583 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1585 -- keep a note of the node id in case we need it for wikipedia in a bit
1586 linked_node_id := linkedPlacex.osm_id;
1587 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1588 --DEBUG: RAISE WARNING 'Linked label member';
1593 IF NEW.centroid IS NULL THEN
1595 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1596 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1598 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1599 and osm_id = substring(relMember.member,2,10000)::bigint
1600 and class = 'place' order by rank_search desc limit 1 LOOP
1602 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1603 -- But that can be fixed by explicitly setting the label in the data
1604 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1605 AND NEW.rank_address = linkedPlacex.rank_address THEN
1607 -- If we don't already have one use this as the centre point of the geometry
1608 IF NEW.centroid IS NULL THEN
1609 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1612 -- merge in the name, re-init word vector
1613 IF NOT linkedPlacex.name IS NULL THEN
1614 NEW.name := linkedPlacex.name || NEW.name;
1615 name_vector := make_keywords(NEW.name);
1618 -- merge in extra tags
1619 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1621 -- mark the linked place (excludes from search results)
1622 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1624 -- keep a note of the node id in case we need it for wikipedia in a bit
1625 linked_node_id := linkedPlacex.osm_id;
1626 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1627 --DEBUG: RAISE WARNING 'Linked admin_center';
1639 -- Name searches can be done for ways as well as relations
1640 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1642 -- not found one yet? how about doing a name search
1643 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1645 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1646 FOR linkedPlacex IN select placex.* from placex WHERE
1647 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1648 AND placex.rank_address = NEW.rank_address
1649 AND placex.place_id != NEW.place_id
1650 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1651 AND st_covers(NEW.geometry, placex.geometry)
1653 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1654 -- If we don't already have one use this as the centre point of the geometry
1655 IF NEW.centroid IS NULL THEN
1656 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1659 -- merge in the name, re-init word vector
1660 NEW.name := linkedPlacex.name || NEW.name;
1661 name_vector := make_keywords(NEW.name);
1663 -- merge in extra tags
1664 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1666 -- mark the linked place (excludes from search results)
1667 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1669 -- keep a note of the node id in case we need it for wikipedia in a bit
1670 linked_node_id := linkedPlacex.osm_id;
1671 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1672 --DEBUG: RAISE WARNING 'Linked named place';
1676 IF NEW.centroid IS NOT NULL THEN
1677 place_centroid := NEW.centroid;
1678 -- Place might have had only a name tag before but has now received translations
1679 -- from the linked place. Make sure a name tag for the default language exists in
1681 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1682 default_language := get_country_language_code(NEW.country_code);
1683 IF default_language IS NOT NULL THEN
1684 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1685 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1686 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1687 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1691 --DEBUG: RAISE WARNING 'Names updated from linked places';
1694 -- Use the maximum importance if a one could be computed from the linked object.
1695 IF linked_importance is not null AND
1696 (NEW.importance is null or NEW.importance < linked_importance) THEN
1697 NEW.importance = linked_importance;
1700 -- Still null? how about looking it up by the node id
1701 IF NEW.importance IS NULL THEN
1702 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1703 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;
1708 -- make sure all names are in the word table
1709 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
1710 perform create_country(NEW.name, lower(NEW.country_code));
1711 --DEBUG: RAISE WARNING 'Country names updated';
1714 NEW.parent_place_id = 0;
1715 parent_place_id_rank = 0;
1718 -- convert address store to array of tokenids
1719 --DEBUG: RAISE WARNING 'Starting address search';
1720 isin_tokens := '{}'::int[];
1721 IF NEW.address IS NOT NULL THEN
1722 FOR addr_item IN SELECT * FROM each(NEW.address)
1724 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1725 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1726 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1727 isin_tokens := isin_tokens || address_street_word_id;
1729 IF NOT %REVERSE-ONLY% THEN
1730 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1731 IF address_street_word_id IS NOT NULL THEN
1732 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1736 IF addr_item.key = 'is_in' THEN
1737 -- is_in items need splitting
1738 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1739 IF array_upper(isin, 1) IS NOT NULL THEN
1740 FOR i IN 1..array_upper(isin, 1) LOOP
1741 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1742 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1743 isin_tokens := isin_tokens || address_street_word_id;
1746 -- merge word into address vector
1747 IF NOT %REVERSE-ONLY% THEN
1748 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1749 IF address_street_word_id IS NOT NULL THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1758 IF NOT %REVERSE-ONLY% THEN
1759 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1762 -- RAISE WARNING 'ISIN: %', isin_tokens;
1764 -- Process area matches
1765 location_rank_search := 0;
1766 location_distance := 0;
1767 location_parent := NULL;
1768 -- added ourself as address already
1769 address_havelevel[NEW.rank_address] := true;
1770 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1772 SELECT * from getNearFeatures(NEW.partition,
1773 CASE WHEN NEW.rank_search >= 26
1774 AND NEW.rank_search < 30
1776 ELSE near_centroid END,
1777 search_maxrank, isin_tokens)
1779 IF location.rank_address != location_rank_search THEN
1780 location_rank_search := location.rank_address;
1781 IF location.isguess THEN
1782 location_distance := location.distance * 1.5;
1784 IF location.rank_address <= 12 THEN
1785 -- for county and above, if we have an area consider that exact
1786 -- (It would be nice to relax the constraint for places close to
1787 -- the boundary but we'd need the exact geometry for that. Too
1789 location_distance = 0;
1791 -- Below county level remain slightly fuzzy.
1792 location_distance := location.distance * 0.5;
1796 CONTINUE WHEN location.keywords <@ location_keywords;
1799 IF location.distance < location_distance OR NOT location.isguess THEN
1800 location_keywords := location.keywords;
1802 location_isaddress := NOT address_havelevel[location.rank_address];
1803 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1804 location_isaddress := ST_Contains(location_parent,location.centroid);
1807 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1808 -- Add it to the list of search terms
1809 IF NOT %REVERSE-ONLY% AND location.rank_search > 4 THEN
1810 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1812 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1813 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1815 IF location_isaddress THEN
1816 -- add postcode if we have one
1817 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1818 IF location.postcode is not null THEN
1819 NEW.postcode = location.postcode;
1822 address_havelevel[location.rank_address] := true;
1823 IF NOT location.isguess THEN
1824 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1827 IF location.rank_address > parent_place_id_rank THEN
1828 NEW.parent_place_id = location.place_id;
1829 parent_place_id_rank = location.rank_address;
1834 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1839 --DEBUG: RAISE WARNING 'address computed';
1841 IF NEW.address is not null AND NEW.address ? 'postcode'
1842 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1843 NEW.postcode := upper(trim(NEW.address->'postcode'));
1846 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1847 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1850 -- if we have a name add this to the name search table
1851 IF NEW.name IS NOT NULL THEN
1853 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1854 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);
1855 --DEBUG: RAISE WARNING 'added to location (full)';
1858 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1859 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1860 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1863 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1864 NEW.rank_search, NEW.rank_address, NEW.geometry);
1865 --DEBUG: RAISE WARNING 'added to search name (full)';
1867 IF NOT %REVERSE-ONLY% THEN
1868 INSERT INTO search_name (place_id, search_rank, address_rank,
1869 importance, country_code, name_vector,
1870 nameaddress_vector, centroid)
1871 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1872 NEW.importance, NEW.country_code, name_vector,
1873 nameaddress_vector, place_centroid);
1878 -- If we've not managed to pick up a better one - default centroid
1879 IF NEW.centroid IS NULL THEN
1880 NEW.centroid := place_centroid;
1883 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1890 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1896 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1898 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1899 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1900 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1901 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1903 IF OLD.rank_address < 30 THEN
1905 -- mark everything linked to this place for re-indexing
1906 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1907 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1908 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1910 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1911 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1913 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1914 b := deleteRoad(OLD.partition, OLD.place_id);
1916 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1917 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1918 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1919 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1920 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1924 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1926 IF OLD.rank_address < 26 THEN
1927 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1930 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1932 IF OLD.name is not null THEN
1933 IF NOT %REVERSE-ONLY% THEN
1934 DELETE from search_name WHERE place_id = OLD.place_id;
1936 b := deleteSearchName(OLD.partition, OLD.place_id);
1939 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1941 DELETE FROM place_addressline where place_id = OLD.place_id;
1943 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1945 -- remove from tables for special search
1946 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1947 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1949 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1952 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1960 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1966 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1968 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1969 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1970 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;
1972 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1978 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;
1980 -- interpolations are special
1981 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
1982 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
1991 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1996 existingplacex RECORD;
1997 existingline RECORD;
1998 existinggeometry GEOMETRY;
1999 existingplace_id BIGINT;
2004 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2005 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2006 -- filter wrong tupels
2007 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
2008 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2009 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2010 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2014 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2015 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2016 -- Have we already done this place?
2017 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;
2019 -- Get the existing place_id
2020 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2022 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2023 IF existing.osm_type IS NULL THEN
2024 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2027 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2028 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2030 -- 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)
2031 IF existingline.osm_id IS NOT NULL THEN
2032 delete from location_property_osmline where osm_id = NEW.osm_id;
2035 -- for interpolations invalidate all nodes on the line
2036 update placex p set indexed_status = 2
2037 from planet_osm_ways w
2038 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2041 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2042 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2045 IF existing.osm_type IS NULL THEN
2049 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2050 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2051 OR existing.geometry::text != NEW.geometry::text
2056 address = NEW.address,
2057 extratags = NEW.extratags,
2058 admin_level = NEW.admin_level,
2059 geometry = NEW.geometry
2060 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2065 ELSE -- insert to placex
2067 -- Patch in additional country names
2068 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2069 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2070 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2071 IF existing.name IS NOT NULL THEN
2072 NEW.name = existing.name || NEW.name;
2076 -- Have we already done this place?
2077 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;
2079 -- Get the existing place_id
2080 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;
2082 -- Handle a place changing type by removing the old data
2083 -- My generated 'place' types are causing havok because they overlap with real keys
2084 -- TODO: move them to their own special purpose key/class to avoid collisions
2085 IF existing.osm_type IS NULL THEN
2086 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2089 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2090 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2093 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2094 AND st_area(existing.geometry) > 0.02
2095 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2096 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2098 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2099 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2100 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2104 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2105 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2107 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2108 IF existingplacex.osm_type IS NULL OR
2109 (existingplacex.class = 'boundary' AND
2110 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2111 (existingplacex.type != NEW.type)))
2114 IF existingplacex.osm_type IS NOT NULL THEN
2115 -- sanity check: ignore admin_level changes on places with too many active children
2116 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2117 --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;
2118 --LIMIT INDEXING: IF i > 100000 THEN
2119 --LIMIT INDEXING: RETURN null;
2120 --LIMIT INDEXING: END IF;
2123 IF existing.osm_type IS NOT NULL THEN
2124 -- pathological case caused by the triggerless copy into place during initial import
2125 -- force delete even for large areas, it will be reinserted later
2126 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;
2127 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2130 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2131 insert into placex (osm_type, osm_id, class, type, name,
2132 admin_level, address, extratags, geometry)
2133 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2134 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2136 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2141 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2142 IF existing.geometry::text != NEW.geometry::text
2143 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2144 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2147 -- Get the version of the geometry actually used (in placex table)
2148 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;
2150 -- Performance limit
2151 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2153 -- 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
2154 update placex set indexed_status = 2 where indexed_status = 0 and
2155 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2156 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2157 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2159 update placex set indexed_status = 2 where indexed_status = 0 and
2160 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2161 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2162 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2169 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2170 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2171 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2172 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2173 OR existing.geometry::text != NEW.geometry::text
2178 address = NEW.address,
2179 extratags = NEW.extratags,
2180 admin_level = NEW.admin_level,
2181 geometry = NEW.geometry
2182 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2185 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2186 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2187 -- postcode was deleted, no longer retain in placex
2188 DELETE FROM placex where place_id = existingplacex.place_id;
2192 NEW.name := hstore('ref', NEW.address->'postcode');
2195 IF NEW.class in ('boundary')
2196 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2197 DELETE FROM placex where place_id = existingplacex.place_id;
2203 address = NEW.address,
2204 parent_place_id = null,
2205 extratags = NEW.extratags,
2206 admin_level = NEW.admin_level,
2208 geometry = NEW.geometry
2209 where place_id = existingplacex.place_id;
2211 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2212 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2213 IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
2214 -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
2215 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);
2218 -- linked places should get potential new naming and addresses
2219 IF existingplacex.linked_place_id is not NULL THEN
2222 extratags = p.extratags,
2225 where x.place_id = existingplacex.linked_place_id
2226 and x.indexed_status = 0
2227 and x.osm_type = p.osm_type
2228 and x.osm_id = p.osm_id
2229 and x.class = p.class;
2234 -- Abort the add (we modified the existing place instead)
2239 $$ LANGUAGE plpgsql;
2242 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2247 IF name is null THEN
2251 FOR j IN 1..array_upper(languagepref,1) LOOP
2252 IF name ? languagepref[j] THEN
2253 result := trim(name->languagepref[j]);
2254 IF result != '' THEN
2260 -- anything will do as a fallback - just take the first name type thing there is
2261 RETURN trim((avals(name))[1]);
2264 LANGUAGE plpgsql IMMUTABLE;
2266 --housenumber only needed for tiger data
2267 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2279 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2280 currresult := trim(get_name_by_language(location.name, languagepref));
2281 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2282 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2283 prevresult := currresult;
2287 RETURN array_to_string(result,', ');
2292 DROP TYPE IF EXISTS addressline CASCADE;
2293 create type addressline as (
2300 admin_level INTEGER,
2303 rank_address INTEGER,
2307 -- Compute the list of address parts for the given place.
2309 -- If in_housenumber is greator or equal 0, look for an interpolation.
2310 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2313 for_place_id BIGINT;
2318 countrylocation RECORD;
2319 searchcountrycode varchar(2);
2320 searchhousenumber TEXT;
2321 searchhousename HSTORE;
2322 searchrankaddress INTEGER;
2323 searchpostcode TEXT;
2324 postcode_isaddress BOOL;
2329 -- The place ein question might not have a direct entry in place_addressline.
2330 -- Look for the parent of such places then and save if in for_place_id.
2332 postcode_isaddress := true;
2334 -- first query osmline (interpolation lines)
2335 IF in_housenumber >= 0 THEN
2336 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
2337 null, 'place', 'house'
2338 FROM location_property_osmline
2339 WHERE place_id = in_place_id AND in_housenumber>=startnumber
2340 AND in_housenumber <= endnumber
2341 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2342 searchpostcode, searchhousename, searchclass, searchtype;
2345 --then query tiger data
2346 -- %NOTIGERDATA% IF 0 THEN
2347 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
2348 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
2350 FROM location_property_tiger
2351 WHERE place_id = in_place_id AND in_housenumber >= startnumber
2352 AND in_housenumber <= endnumber
2353 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2354 searchpostcode, searchhousename, searchclass, searchtype;
2356 -- %NOTIGERDATA% END IF;
2358 -- %NOAUXDATA% IF 0 THEN
2359 IF for_place_id IS NULL THEN
2360 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
2361 FROM location_property_aux
2362 WHERE place_id = in_place_id
2363 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
2364 searchpostcode, searchhousename, searchclass, searchtype;
2366 -- %NOAUXDATA% END IF;
2369 IF for_place_id IS NULL THEN
2370 SELECT parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2371 FROM location_postcode
2372 WHERE place_id = in_place_id
2373 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
2374 searchclass, searchtype;
2377 -- POI objects in the placex table
2378 IF for_place_id IS NULL THEN
2379 SELECT parent_place_id, country_code, housenumber, rank_search, postcode,
2382 WHERE place_id = in_place_id and rank_search > 27
2383 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2384 searchpostcode, searchhousename, searchclass, searchtype;
2387 -- If for_place_id is still NULL at this point then the object has its own
2388 -- entry in place_address line. However, still check if there is not linked
2389 -- place we should be using instead.
2390 IF for_place_id IS NULL THEN
2391 select coalesce(linked_place_id, place_id), country_code,
2392 housenumber, rank_search, postcode, null
2393 from placex where place_id = in_place_id
2394 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2397 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2399 found := 1000; -- the lowest rank_address included
2401 -- Return the record for the base entry.
2403 SELECT placex.place_id, osm_type, osm_id, name,
2404 class, type, admin_level,
2405 type not in ('postcode', 'postal_code') as isaddress,
2406 CASE WHEN rank_address = 0 THEN 100
2407 WHEN rank_address = 11 THEN 5
2408 ELSE rank_address END as rank_address,
2409 0 as distance, country_code, postcode
2411 WHERE place_id = for_place_id
2413 --RAISE WARNING '%',location;
2414 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2415 searchcountrycode := location.country_code;
2417 IF location.rank_address < 4 THEN
2418 -- no country locations for ranks higher than country
2419 searchcountrycode := NULL;
2421 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2422 location.name, location.class, location.type,
2423 location.admin_level, true, location.isaddress,
2424 location.rank_address, location.distance)::addressline;
2425 RETURN NEXT countrylocation;
2426 found := location.rank_address;
2430 SELECT placex.place_id, osm_type, osm_id, name,
2431 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2432 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2433 admin_level, fromarea, isaddress and linked_place_id is NULL as isaddress,
2434 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2435 distance, country_code, postcode
2436 FROM place_addressline join placex on (address_place_id = placex.place_id)
2437 WHERE place_addressline.place_id = for_place_id
2438 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
2439 AND linked_place_id is null
2440 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
2441 OR placex.country_code = searchcountrycode)
2442 ORDER BY rank_address desc, isaddress desc, fromarea desc,
2443 distance asc, rank_search desc
2445 --RAISE WARNING '%',location;
2446 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2447 searchcountrycode := location.country_code;
2449 IF location.type in ('postcode', 'postal_code') THEN
2450 postcode_isaddress := false;
2451 IF location.osm_type != 'R' THEN
2452 location.isaddress := FALSE;
2455 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2456 location.name, location.class, location.type,
2457 location.admin_level, location.fromarea,
2458 location.isaddress, location.rank_address,
2459 location.distance)::addressline;
2460 RETURN NEXT countrylocation;
2461 found := location.rank_address;
2464 -- If no country was included yet, add the name information from country_name.
2466 SELECT name FROM country_name
2467 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
2468 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2469 IF countryname IS NOT NULL THEN
2470 location := ROW(null, null, null, countryname, 'place', 'country',
2471 null, true, true, 4, 0)::addressline;
2472 RETURN NEXT location;
2476 -- Finally add some artificial rows.
2477 IF searchcountrycode IS NOT NULL THEN
2478 location := ROW(null, null, null, hstore('ref', searchcountrycode),
2479 'place', 'country_code', null, true, false, 4, 0)::addressline;
2480 RETURN NEXT location;
2483 IF searchhousename IS NOT NULL THEN
2484 location := ROW(in_place_id, null, null, searchhousename, searchclass,
2485 searchtype, null, true, true, 29, 0)::addressline;
2486 RETURN NEXT location;
2489 IF searchhousenumber IS NOT NULL THEN
2490 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber),
2491 'place', 'house_number', null, true, true, 28, 0)::addressline;
2492 RETURN NEXT location;
2495 IF searchpostcode IS NOT NULL THEN
2496 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
2497 'postcode', null, false, postcode_isaddress, 5, 0)::addressline;
2498 RETURN NEXT location;
2507 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2508 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2513 place_centroid GEOMETRY;
2514 out_partition INTEGER;
2515 out_parent_place_id BIGINT;
2517 address_street_word_id INTEGER;
2522 place_centroid := ST_Centroid(pointgeo);
2523 out_partition := get_partition(in_countrycode);
2524 out_parent_place_id := null;
2526 address_street_word_id := get_name_id(make_standard_name(in_street));
2527 IF address_street_word_id IS NOT NULL THEN
2528 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2529 out_parent_place_id := location.place_id;
2533 IF out_parent_place_id IS NULL THEN
2534 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2535 out_parent_place_id := location.place_id;
2539 out_postcode := in_postcode;
2540 IF out_postcode IS NULL THEN
2541 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2543 -- XXX look into postcode table
2546 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2547 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2548 newpoints := newpoints + 1;
2555 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2562 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2563 IF members[i+1] = member THEN
2564 result := result || members[i];
2573 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2579 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2580 IF members[i+1] = ANY(memberLabels) THEN
2581 RETURN NEXT members[i];
2590 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2591 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2593 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2594 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
2595 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2596 ), '') AS bytea), 'UTF8');
2598 LANGUAGE SQL IMMUTABLE STRICT;
2600 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2604 RETURN decode_url_part(p);
2606 WHEN others THEN return null;
2609 LANGUAGE plpgsql IMMUTABLE;
2611 DROP TYPE wikipedia_article_match CASCADE;
2612 create type wikipedia_article_match as (
2618 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2624 wiki_article_title TEXT;
2625 wiki_article_language TEXT;
2626 result wikipedia_article_match;
2628 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'];
2630 WHILE langs[i] IS NOT NULL LOOP
2631 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2632 IF wiki_article is not null THEN
2633 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2634 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2635 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2636 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2637 wiki_article := replace(wiki_article,' ','_');
2638 IF strpos(wiki_article, ':') IN (3,4) THEN
2639 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2640 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2642 wiki_article_title := trim(wiki_article);
2643 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;
2646 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2647 from wikipedia_article
2648 where language = wiki_article_language and
2649 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2651 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2652 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2653 where wikipedia_redirect.language = wiki_article_language and
2654 (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'\\',''))
2655 order by importance desc limit 1 INTO result;
2657 IF result.language is not null THEN
2668 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2669 RETURNS SETOF GEOMETRY
2683 remainingdepth INTEGER;
2688 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2690 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2691 RETURN NEXT geometry;
2695 remainingdepth := maxdepth - 1;
2696 area := ST_AREA(geometry);
2697 IF remainingdepth < 1 OR area < maxarea THEN
2698 RETURN NEXT geometry;
2702 xmin := st_xmin(geometry);
2703 xmax := st_xmax(geometry);
2704 ymin := st_ymin(geometry);
2705 ymax := st_ymax(geometry);
2706 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2708 -- if the geometry completely covers the box don't bother to slice any more
2709 IF ST_AREA(secbox) = area THEN
2710 RETURN NEXT geometry;
2714 xmid := (xmin+xmax)/2;
2715 ymid := (ymin+ymax)/2;
2718 FOR seg IN 1..4 LOOP
2721 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2724 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2727 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2730 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2733 IF st_intersects(geometry, secbox) THEN
2734 secgeo := st_intersection(geometry, secbox);
2735 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2736 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2737 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2739 RETURN NEXT geo.geom;
2751 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2752 RETURNS SETOF GEOMETRY
2757 -- 10000000000 is ~~ 1x1 degree
2758 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2759 RETURN NEXT geo.geom;
2767 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2771 osmtype character(1);
2775 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2776 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2777 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2778 -- force delete from place/placex by making it a very small geometry
2779 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;
2780 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2787 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2795 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2796 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2797 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2798 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2799 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2800 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2801 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'));
2802 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2803 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'));
2809 ELSEIF rank < 18 THEN
2811 ELSEIF rank < 20 THEN
2813 ELSEIF rank = 21 THEN
2815 ELSEIF rank < 24 THEN
2817 ELSEIF rank < 26 THEN
2818 diameter := 0.002; -- 100 to 200 meters
2819 ELSEIF rank < 28 THEN
2820 diameter := 0.001; -- 50 to 100 meters
2822 IF diameter > 0 THEN
2824 -- roads may cause reparenting for >27 rank places
2825 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2826 ELSEIF rank >= 16 THEN
2827 -- up to rank 16, street-less addresses may need reparenting
2828 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');
2830 -- for all other places the search terms may change as well
2831 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);