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 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;
771 CREATE OR REPLACE FUNCTION osmline_reinsert(node_id BIGINT, geom GEOMETRY)
777 SELECT w.id FROM planet_osm_ways w, location_property_osmline p
778 WHERE p.linegeo && geom and p.osm_id = w.id and p.indexed_status = 0
779 and node_id = any(w.nodes) INTO existingline;
781 IF existingline.id is not NULL THEN
782 DELETE FROM location_property_osmline WHERE osm_id = existingline.id;
783 INSERT INTO location_property_osmline (osm_id, address, linegeo)
784 SELECT osm_id, address, geometry FROM place
785 WHERE osm_type = 'W' and osm_id = existingline.id;
794 CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
797 NEW.place_id := nextval('seq_place');
798 NEW.indexed_date := now();
800 IF NEW.indexed_status IS NULL THEN
801 IF NEW.address is NULL OR NOT NEW.address ? 'interpolation'
802 OR NEW.address->'interpolation' NOT IN ('odd', 'even', 'all') THEN
803 -- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
807 NEW.indexed_status := 1; --STATUS_NEW
808 NEW.country_code := lower(get_country_code(NEW.linegeo));
810 NEW.partition := get_partition(NEW.country_code);
811 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.linegeo);
820 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
827 country_code VARCHAR(2);
828 default_language VARCHAR(10);
833 --DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
835 NEW.place_id := nextval('seq_place');
836 NEW.indexed_status := 1; --STATUS_NEW
838 NEW.country_code := lower(get_country_code(NEW.geometry));
840 NEW.partition := get_partition(NEW.country_code);
841 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
843 -- copy 'name' to or from the default language (if there is a default language)
844 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
845 default_language := get_country_language_code(NEW.country_code);
846 IF default_language IS NOT NULL THEN
847 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
848 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
849 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
850 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
855 IF NEW.osm_type = 'X' THEN
856 -- E'X'ternal records should already be in the right format so do nothing
858 is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
860 IF NEW.class in ('place','boundary')
861 AND NEW.type in ('postcode','postal_code') THEN
863 IF NEW.address IS NULL OR NOT NEW.address ? 'postcode' THEN
864 -- most likely just a part of a multipolygon postcode boundary, throw it away
868 NEW.name := hstore('ref', NEW.address->'postcode');
870 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
871 INTO NEW.rank_search, NEW.rank_address;
874 NEW.rank_address := 0;
876 ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
878 ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
879 AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
881 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
883 ELSEIF NEW.osm_type = 'N' AND NEW.class = 'highway' THEN
884 NEW.rank_search = 30;
885 NEW.rank_address = 0;
886 ELSEIF NEW.class = 'landuse' AND NOT is_area THEN
887 NEW.rank_search = 30;
888 NEW.rank_address = 0;
890 -- do table lookup stuff
891 IF NEW.class = 'boundary' and NEW.type = 'administrative' THEN
892 classtype = NEW.type || NEW.admin_level::TEXT;
894 classtype = NEW.type;
896 SELECT l.rank_search, l.rank_address FROM address_levels l
897 WHERE (l.country_code = NEW.country_code or l.country_code is NULL)
898 AND l.class = NEW.class AND (l.type = classtype or l.type is NULL)
899 ORDER BY l.country_code, l.class, l.type LIMIT 1
900 INTO NEW.rank_search, NEW.rank_address;
902 IF NEW.rank_search is NULL THEN
903 NEW.rank_search := 30;
906 IF NEW.rank_address is NULL THEN
907 NEW.rank_address := 30;
911 -- some postcorrections
912 IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
913 -- Slightly promote waterway relations so that they are processed
914 -- before their members.
915 NEW.rank_search := NEW.rank_search - 1;
918 IF (NEW.extratags -> 'capital') = 'yes' THEN
919 NEW.rank_search := NEW.rank_search - 1;
924 -- a country code make no sense below rank 4 (country)
925 IF NEW.rank_search < 4 THEN
926 NEW.country_code := NULL;
929 --DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
931 RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
933 IF NEW.osm_type = 'N' and NEW.rank_search > 28 THEN
934 -- might be part of an interpolation
935 result := osmline_reinsert(NEW.osm_id, NEW.geometry);
936 ELSEIF NEW.rank_address > 0 THEN
937 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
938 -- Performance: We just can't handle re-indexing for country level changes
939 IF st_area(NEW.geometry) < 1 THEN
940 -- mark items within the geometry for re-indexing
941 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
943 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
944 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
945 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'));
946 update placex set indexed_status = 2 where (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
947 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'));
950 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
952 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
953 IF NEW.type='postcode' THEN
955 ELSEIF NEW.rank_search < 16 THEN
957 ELSEIF NEW.rank_search < 18 THEN
959 ELSEIF NEW.rank_search < 20 THEN
961 ELSEIF NEW.rank_search = 21 THEN
963 ELSEIF NEW.rank_search < 24 THEN
965 ELSEIF NEW.rank_search < 26 THEN
966 diameter := 0.002; -- 100 to 200 meters
967 ELSEIF NEW.rank_search < 28 THEN
968 diameter := 0.001; -- 50 to 100 meters
971 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
972 IF NEW.rank_search >= 26 THEN
973 -- roads may cause reparenting for >27 rank places
974 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW.rank_search and ST_DWithin(placex.geometry, NEW.geometry, diameter);
975 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
976 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin(location_property_osmline.linegeo, NEW.geometry, diameter);
977 ELSEIF NEW.rank_search >= 16 THEN
978 -- up to rank 16, street-less addresses may need reparenting
979 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');
981 -- for all other places the search terms may change as well
982 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);
989 -- add to tables for special search
990 -- Note: won't work on initial import because the classtype tables
991 -- do not yet exist. It won't hurt either.
992 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
993 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO result;
995 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
996 USING NEW.place_id, ST_Centroid(NEW.geometry);
1005 CREATE OR REPLACE FUNCTION osmline_update() RETURNS
1009 place_centroid GEOMETRY;
1013 startnumber INTEGER;
1018 sectiongeo GEOMETRY;
1019 interpol_postcode TEXT;
1023 IF OLD.indexed_status = 100 THEN
1024 delete from location_property_osmline where place_id = OLD.place_id;
1028 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1032 NEW.interpolationtype = NEW.address->'interpolation';
1034 place_centroid := ST_PointOnSurface(NEW.linegeo);
1035 NEW.parent_place_id = get_interpolation_parent(NEW.osm_id, NEW.address->'street',
1036 NEW.address->'place',
1037 NEW.partition, place_centroid, NEW.linegeo);
1039 IF NEW.address is not NULL AND NEW.address ? 'postcode' AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1040 interpol_postcode := NEW.address->'postcode';
1041 housenum := getorcreate_postcode_id(NEW.address->'postcode');
1043 interpol_postcode := NULL;
1046 -- if the line was newly inserted, split the line as necessary
1047 IF OLD.indexed_status = 1 THEN
1048 select nodes from planet_osm_ways where id = NEW.osm_id INTO waynodes;
1050 IF array_upper(waynodes, 1) IS NULL THEN
1054 linegeo := NEW.linegeo;
1055 startnumber := NULL;
1057 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
1059 select osm_id, address, geometry
1060 from place where osm_type = 'N' and osm_id = waynodes[nodeidpos]::BIGINT
1061 and address is not NULL and address ? 'housenumber' limit 1 INTO nextnode;
1062 --RAISE NOTICE 'Nextnode.place_id: %s', nextnode.place_id;
1063 IF nextnode.osm_id IS NOT NULL THEN
1064 --RAISE NOTICE 'place_id is not null';
1065 IF nodeidpos > 1 and nodeidpos < array_upper(waynodes, 1) THEN
1066 -- Make sure that the point is actually on the line. That might
1067 -- be a bit paranoid but ensures that the algorithm still works
1068 -- should osm2pgsql attempt to repair geometries.
1069 splitline := split_line_on_node(linegeo, nextnode.geometry);
1070 sectiongeo := ST_GeometryN(splitline, 1);
1071 linegeo := ST_GeometryN(splitline, 2);
1073 sectiongeo = linegeo;
1075 endnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1077 IF startnumber IS NOT NULL AND endnumber IS NOT NULL
1078 AND startnumber != endnumber
1079 AND ST_GeometryType(sectiongeo) = 'ST_LineString' THEN
1081 IF (startnumber > endnumber) THEN
1082 housenum := endnumber;
1083 endnumber := startnumber;
1084 startnumber := housenum;
1085 sectiongeo := ST_Reverse(sectiongeo);
1088 -- determine postcode
1089 postcode := coalesce(interpol_postcode,
1090 prevnode.address->'postcode',
1091 nextnode.address->'postcode',
1094 IF postcode is NULL THEN
1095 SELECT placex.postcode FROM placex WHERE place_id = NEW.parent_place_id INTO postcode;
1097 IF postcode is NULL THEN
1098 postcode := get_nearest_postcode(NEW.country_code, nextnode.geometry);
1101 IF NEW.startnumber IS NULL THEN
1102 NEW.startnumber := startnumber;
1103 NEW.endnumber := endnumber;
1104 NEW.linegeo := sectiongeo;
1105 NEW.postcode := upper(trim(postcode));
1107 insert into location_property_osmline
1108 (linegeo, partition, osm_id, parent_place_id,
1109 startnumber, endnumber, interpolationtype,
1110 address, postcode, country_code,
1111 geometry_sector, indexed_status)
1112 values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
1113 startnumber, endnumber, NEW.interpolationtype,
1114 NEW.address, postcode,
1115 NEW.country_code, NEW.geometry_sector, 0);
1119 -- early break if we are out of line string,
1120 -- might happen when a line string loops back on itself
1121 IF ST_GeometryType(linegeo) != 'ST_LineString' THEN
1125 startnumber := substring(nextnode.address->'housenumber','[0-9]+')::integer;
1126 prevnode := nextnode;
1131 -- marking descendants for reparenting is not needed, because there are
1132 -- actually no descendants for interpolation lines
1138 -- Trigger for updates of location_postcode
1140 -- Computes the parent object the postcode most likely refers to.
1141 -- This will be the place that determines the address displayed when
1142 -- searching for this postcode.
1143 CREATE OR REPLACE FUNCTION postcode_update() RETURNS
1150 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1154 NEW.indexed_date = now();
1156 partition := get_partition(NEW.country_code);
1158 SELECT * FROM get_postcode_rank(NEW.country_code, NEW.postcode)
1159 INTO NEW.rank_search, NEW.rank_address;
1161 NEW.parent_place_id = 0;
1164 FROM getNearFeatures(partition, NEW.geometry, NEW.rank_search, '{}'::int[])
1165 WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
1167 NEW.parent_place_id = location.place_id;
1175 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1180 place_centroid GEOMETRY;
1181 near_centroid GEOMETRY;
1183 search_maxdistance FLOAT[];
1184 search_mindistance FLOAT[];
1185 address_havelevel BOOLEAN[];
1192 relation_members TEXT[];
1194 linkedplacex RECORD;
1196 search_diameter FLOAT;
1197 search_prevdiameter FLOAT;
1198 search_maxrank INTEGER;
1199 address_maxrank INTEGER;
1200 address_street_word_id INTEGER;
1201 address_street_word_ids INTEGER[];
1202 parent_place_id_rank BIGINT;
1210 location_rank_search INTEGER;
1211 location_distance FLOAT;
1212 location_parent GEOMETRY;
1213 location_isaddress BOOLEAN;
1214 location_keywords INTEGER[];
1216 default_language TEXT;
1217 name_vector INTEGER[];
1218 nameaddress_vector INTEGER[];
1220 linked_node_id BIGINT;
1221 linked_importance FLOAT;
1222 linked_wikipedia TEXT;
1227 IF OLD.indexed_status = 100 THEN
1228 --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
1229 delete from placex where place_id = OLD.place_id;
1233 IF NEW.indexed_status != 0 OR OLD.indexed_status = 0 THEN
1237 --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
1239 NEW.indexed_date = now();
1241 IF NOT %REVERSE-ONLY% THEN
1242 DELETE from search_name WHERE place_id = NEW.place_id;
1244 result := deleteSearchName(NEW.partition, NEW.place_id);
1245 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1246 result := deleteRoad(NEW.partition, NEW.place_id);
1247 result := deleteLocationArea(NEW.partition, NEW.place_id, NEW.rank_search);
1248 UPDATE placex set linked_place_id = null, indexed_status = 2
1249 where linked_place_id = NEW.place_id;
1250 -- update not necessary for osmline, cause linked_place_id does not exist
1252 IF NEW.linked_place_id is not null THEN
1253 --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
1257 --DEBUG: RAISE WARNING 'Copy over address tags';
1258 -- housenumber is a computed field, so start with an empty value
1259 NEW.housenumber := NULL;
1260 IF NEW.address is not NULL THEN
1261 IF NEW.address ? 'conscriptionnumber' THEN
1262 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
1263 IF NEW.address ? 'streetnumber' THEN
1264 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1265 NEW.housenumber := (NEW.address->'conscriptionnumber') || '/' || (NEW.address->'streetnumber');
1267 NEW.housenumber := NEW.address->'conscriptionnumber';
1269 ELSEIF NEW.address ? 'streetnumber' THEN
1270 NEW.housenumber := NEW.address->'streetnumber';
1271 i := getorcreate_housenumber_id(make_standard_name(NEW.address->'streetnumber'));
1272 ELSEIF NEW.address ? 'housenumber' THEN
1273 NEW.housenumber := NEW.address->'housenumber';
1274 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
1277 addr_street := NEW.address->'street';
1278 addr_place := NEW.address->'place';
1280 IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
1281 i := getorcreate_postcode_id(NEW.address->'postcode');
1285 -- Speed up searches - just use the centroid of the feature
1286 -- cheaper but less acurate
1287 place_centroid := ST_PointOnSurface(NEW.geometry);
1288 -- For searching near features rather use the centroid
1289 near_centroid := ST_Centroid(NEW.geometry);
1290 NEW.centroid := null;
1291 NEW.postcode := null;
1292 --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
1294 -- recalculate country and partition
1295 IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
1296 -- for countries, believe the mapped country code,
1297 -- so that we remain in the right partition if the boundaries
1299 NEW.country_code := lower(NEW.address->'country');
1300 NEW.partition := get_partition(lower(NEW.country_code));
1301 IF NEW.partition = 0 THEN
1302 NEW.country_code := lower(get_country_code(place_centroid));
1303 NEW.partition := get_partition(NEW.country_code);
1306 IF NEW.rank_search >= 4 THEN
1307 NEW.country_code := lower(get_country_code(place_centroid));
1309 NEW.country_code := NULL;
1311 NEW.partition := get_partition(NEW.country_code);
1313 --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
1315 -- waterway ways are linked when they are part of a relation and have the same class/type
1316 IF NEW.osm_type = 'R' and NEW.class = 'waterway' THEN
1317 FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
1319 FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
1320 IF relation_members[i+1] in ('', 'main_stream', 'side_stream') AND substring(relation_members[i],1,1) = 'w' THEN
1321 --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
1322 FOR linked_node_id IN SELECT place_id FROM placex
1323 WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
1324 and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
1325 and ( relation_members[i+1] != 'side_stream' or NEW.name->'name' = name->'name')
1327 UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
1332 --DEBUG: RAISE WARNING 'Waterway processed';
1335 -- What level are we searching from
1336 search_maxrank := NEW.rank_search;
1338 -- Thought this wasn't needed but when we add new languages to the country_name table
1339 -- we need to update the existing names
1340 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1341 default_language := get_country_language_code(NEW.country_code);
1342 IF default_language IS NOT NULL THEN
1343 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1344 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1345 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1346 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1350 --DEBUG: RAISE WARNING 'Local names updated';
1352 -- Initialise the name vector using our name
1353 name_vector := make_keywords(NEW.name);
1354 nameaddress_vector := '{}'::int[];
1357 address_havelevel[i] := false;
1360 NEW.importance := null;
1361 select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
1362 IF NEW.importance IS NULL THEN
1363 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;
1366 --DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
1368 -- ---------------------------------------------------------------------------
1369 -- For low level elements we inherit from our parent road
1370 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1372 --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
1374 -- We won't get a better centroid, besides these places are too small to care
1375 NEW.centroid := place_centroid;
1377 NEW.parent_place_id := null;
1379 -- if we have a POI and there is no address information,
1380 -- see if we can get it from a surrounding building
1381 IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
1382 AND NEW.housenumber IS NULL THEN
1383 FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
1384 and address is not null
1385 and (address ? 'housenumber' or address ? 'street' or address ? 'place')
1386 and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
1389 NEW.housenumber := location.address->'housenumber';
1390 addr_street := location.address->'street';
1391 addr_place := location.address->'place';
1392 --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
1396 -- We have to find our parent road.
1397 -- Copy data from linked items (points on ways, addr:street links, relations)
1399 -- Is this object part of a relation?
1400 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id] and members @> ARRAY[lower(NEW.osm_type)||NEW.osm_id]
1402 -- At the moment we only process one type of relation - associatedStreet
1403 IF relation.tags @> ARRAY['associatedStreet'] THEN
1404 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1405 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1406 --RAISE WARNING 'node in relation %',relation;
1407 SELECT place_id from placex where osm_type = 'W'
1408 and osm_id = substring(relation.members[i],2,200)::bigint
1409 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1414 --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
1416 -- Note that addr:street links can only be indexed once the street itself is indexed
1417 IF NEW.parent_place_id IS NULL AND addr_street IS NOT NULL THEN
1418 address_street_word_ids := get_name_ids(make_standard_name(addr_street));
1419 IF address_street_word_ids IS NOT NULL THEN
1420 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1423 --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
1425 IF NEW.parent_place_id IS NULL AND addr_place IS NOT NULL THEN
1426 address_street_word_ids := get_name_ids(make_standard_name(addr_place));
1427 IF address_street_word_ids IS NOT NULL THEN
1428 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1431 --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
1433 -- Is this node part of an interpolation?
1434 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1435 SELECT q.parent_place_id FROM location_property_osmline q, planet_osm_ways x
1436 WHERE q.linegeo && NEW.geometry and x.id = q.osm_id and NEW.osm_id = any(x.nodes)
1437 LIMIT 1 INTO NEW.parent_place_id;
1439 --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
1441 -- Is this node part of a way?
1442 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1445 SELECT p.place_id, p.osm_id, p.rank_search, p.address from placex p, planet_osm_ways w
1446 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)
1448 --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
1450 -- Way IS a road then we are on it - that must be our road
1451 IF location.rank_search < 28 THEN
1452 --RAISE WARNING 'node in way that is a street %',location;
1453 NEW.parent_place_id := location.place_id;
1456 --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
1458 -- If the way mentions a street or place address, try that for parenting.
1459 IF location.address is not null THEN
1460 IF location.address ? 'street' THEN
1461 address_street_word_ids := get_name_ids(make_standard_name(location.address->'street'));
1462 IF address_street_word_ids IS NOT NULL THEN
1463 SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1464 EXIT WHEN NEW.parent_place_id is not NULL;
1467 --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
1469 IF location.address ? 'place' THEN
1470 address_street_word_ids := get_name_ids(make_standard_name(location.address->'place'));
1471 IF address_street_word_ids IS NOT NULL THEN
1472 SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
1473 EXIT WHEN NEW.parent_place_id is not NULL;
1476 --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
1479 -- Is the WAY part of a relation
1480 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id] and members @> ARRAY['w'||location.osm_id]
1482 -- At the moment we only process one type of relation - associatedStreet
1483 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1484 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1485 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1486 --RAISE WARNING 'node in way that is in a relation %',relation;
1487 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::bigint
1488 and rank_search = 26 and name is not null INTO NEW.parent_place_id;
1493 EXIT WHEN NEW.parent_place_id is not null;
1494 --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
1499 -- Still nothing, just use the nearest road
1500 IF NEW.parent_place_id IS NULL THEN
1501 SELECT place_id FROM getNearestRoadFeature(NEW.partition, near_centroid) INTO NEW.parent_place_id;
1503 --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
1506 -- If we didn't find any road fallback to standard method
1507 IF NEW.parent_place_id IS NOT NULL THEN
1509 -- Get the details of the parent road
1510 SELECT p.country_code, p.postcode FROM placex p
1511 WHERE p.place_id = NEW.parent_place_id INTO location;
1513 NEW.country_code := location.country_code;
1514 --DEBUG: RAISE WARNING 'Got parent details from search name';
1516 -- determine postcode
1517 IF NEW.rank_search > 4 THEN
1518 IF NEW.address is not null AND NEW.address ? 'postcode' THEN
1519 NEW.postcode = upper(trim(NEW.address->'postcode'));
1521 NEW.postcode := location.postcode;
1523 IF NEW.postcode is null THEN
1524 NEW.postcode := get_nearest_postcode(NEW.country_code, near_centroid);
1528 -- If there is no name it isn't searchable, don't bother to create a search record
1529 IF NEW.name is NULL THEN
1530 --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
1534 -- Performance, it would be more acurate to do all the rest of the import
1535 -- process but it takes too long
1536 -- Just be happy with inheriting from parent road only
1537 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1538 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);
1539 --DEBUG: RAISE WARNING 'Place added to location table';
1542 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1543 NEW.rank_search, NEW.rank_address, NEW.geometry);
1545 IF NOT %REVERSE-ONLY% THEN
1546 -- Merge address from parent
1547 SELECT s.name_vector, s.nameaddress_vector FROM search_name s
1548 WHERE s.place_id = NEW.parent_place_id INTO location;
1550 nameaddress_vector := array_merge(nameaddress_vector,
1551 location.nameaddress_vector);
1552 nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
1554 INSERT INTO search_name (place_id, search_rank, address_rank,
1555 importance, country_code, name_vector,
1556 nameaddress_vector, centroid)
1557 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1558 NEW.importance, NEW.country_code, name_vector,
1559 nameaddress_vector, place_centroid);
1560 --DEBUG: RAISE WARNING 'Place added to search table';
1568 -- ---------------------------------------------------------------------------
1570 --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
1572 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1574 -- see if we have any special relation members
1575 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1576 --DEBUG: RAISE WARNING 'Got relation members';
1578 IF relation_members IS NOT NULL THEN
1579 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1580 --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
1582 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1583 and osm_id = substring(relMember.member,2,10000)::bigint
1584 and class = 'place' order by rank_search desc limit 1 LOOP
1586 -- If we don't already have one use this as the centre point of the geometry
1587 IF NEW.centroid IS NULL THEN
1588 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1591 -- merge in the label name, re-init word vector
1592 IF NOT linkedPlacex.name IS NULL THEN
1593 NEW.name := linkedPlacex.name || NEW.name;
1594 name_vector := array_merge(name_vector, make_keywords(linkedPlacex.name));
1597 -- merge in extra tags
1598 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1600 -- mark the linked place (excludes from search results)
1601 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1603 -- keep a note of the node id in case we need it for wikipedia in a bit
1604 linked_node_id := linkedPlacex.osm_id;
1605 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1606 --DEBUG: RAISE WARNING 'Linked label member';
1611 IF NEW.centroid IS NULL THEN
1613 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1614 --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
1616 FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
1617 and osm_id = substring(relMember.member,2,10000)::bigint
1618 and class = 'place' order by rank_search desc limit 1 LOOP
1620 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1621 -- But that can be fixed by explicitly setting the label in the data
1622 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1623 AND NEW.rank_address = linkedPlacex.rank_address THEN
1625 -- If we don't already have one use this as the centre point of the geometry
1626 IF NEW.centroid IS NULL THEN
1627 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1630 -- merge in the name, re-init word vector
1631 IF NOT linkedPlacex.name IS NULL THEN
1632 NEW.name := linkedPlacex.name || NEW.name;
1633 name_vector := make_keywords(NEW.name);
1636 -- merge in extra tags
1637 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1639 -- mark the linked place (excludes from search results)
1640 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1642 -- keep a note of the node id in case we need it for wikipedia in a bit
1643 linked_node_id := linkedPlacex.osm_id;
1644 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1645 --DEBUG: RAISE WARNING 'Linked admin_center';
1657 -- Name searches can be done for ways as well as relations
1658 IF NEW.osm_type in ('W','R') AND NEW.rank_search < 26 AND NEW.rank_address > 0 THEN
1660 -- not found one yet? how about doing a name search
1661 IF NEW.centroid IS NULL AND (NEW.name->'name') is not null and make_standard_name(NEW.name->'name') != '' THEN
1663 --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
1664 FOR linkedPlacex IN select placex.* from placex WHERE
1665 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1666 AND placex.rank_address = NEW.rank_address
1667 AND placex.place_id != NEW.place_id
1668 AND placex.osm_type = 'N'::char(1) AND placex.rank_search < 26
1669 AND st_covers(NEW.geometry, placex.geometry)
1671 --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
1672 -- If we don't already have one use this as the centre point of the geometry
1673 IF NEW.centroid IS NULL THEN
1674 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1677 -- merge in the name, re-init word vector
1678 NEW.name := linkedPlacex.name || NEW.name;
1679 name_vector := make_keywords(NEW.name);
1681 -- merge in extra tags
1682 NEW.extratags := hstore(linkedPlacex.class, linkedPlacex.type) || coalesce(linkedPlacex.extratags, ''::hstore) || coalesce(NEW.extratags, ''::hstore);
1684 -- mark the linked place (excludes from search results)
1685 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1687 -- keep a note of the node id in case we need it for wikipedia in a bit
1688 linked_node_id := linkedPlacex.osm_id;
1689 select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
1690 --DEBUG: RAISE WARNING 'Linked named place';
1694 IF NEW.centroid IS NOT NULL THEN
1695 place_centroid := NEW.centroid;
1696 -- Place might have had only a name tag before but has now received translations
1697 -- from the linked place. Make sure a name tag for the default language exists in
1699 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1700 default_language := get_country_language_code(NEW.country_code);
1701 IF default_language IS NOT NULL THEN
1702 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1703 NEW.name := NEW.name || hstore(('name:'||default_language), (NEW.name -> 'name'));
1704 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1705 NEW.name := NEW.name || hstore('name', (NEW.name -> ('name:'||default_language)));
1709 --DEBUG: RAISE WARNING 'Names updated from linked places';
1712 -- Use the maximum importance if a one could be computed from the linked object.
1713 IF linked_importance is not null AND
1714 (NEW.importance is null or NEW.importance < linked_importance) THEN
1715 NEW.importance = linked_importance;
1718 -- Still null? how about looking it up by the node id
1719 IF NEW.importance IS NULL THEN
1720 --DEBUG: RAISE WARNING 'Looking up importance by linked node id';
1721 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;
1726 -- make sure all names are in the word table
1727 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
1728 perform create_country(NEW.name, lower(NEW.country_code));
1729 --DEBUG: RAISE WARNING 'Country names updated';
1732 NEW.parent_place_id = 0;
1733 parent_place_id_rank = 0;
1736 -- convert address store to array of tokenids
1737 --DEBUG: RAISE WARNING 'Starting address search';
1738 isin_tokens := '{}'::int[];
1739 IF NEW.address IS NOT NULL THEN
1740 FOR addr_item IN SELECT * FROM each(NEW.address)
1742 IF addr_item.key IN ('city', 'tiger:county', 'state', 'suburb', 'province', 'district', 'region', 'county', 'municipality', 'hamlet', 'village', 'subdistrict', 'town', 'neighbourhood', 'quarter', 'parish') THEN
1743 address_street_word_id := get_name_id(make_standard_name(addr_item.value));
1744 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1745 isin_tokens := isin_tokens || address_street_word_id;
1747 IF NOT %REVERSE-ONLY% THEN
1748 address_street_word_id := get_word_id(make_standard_name(addr_item.value));
1749 IF address_street_word_id IS NOT NULL THEN
1750 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1754 IF addr_item.key = 'is_in' THEN
1755 -- is_in items need splitting
1756 isin := regexp_split_to_array(addr_item.value, E'[;,]');
1757 IF array_upper(isin, 1) IS NOT NULL THEN
1758 FOR i IN 1..array_upper(isin, 1) LOOP
1759 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1760 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1761 isin_tokens := isin_tokens || address_street_word_id;
1764 -- merge word into address vector
1765 IF NOT %REVERSE-ONLY% THEN
1766 address_street_word_id := get_word_id(make_standard_name(isin[i]));
1767 IF address_street_word_id IS NOT NULL THEN
1768 nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
1776 IF NOT %REVERSE-ONLY% THEN
1777 nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
1780 -- RAISE WARNING 'ISIN: %', isin_tokens;
1782 -- Process area matches
1783 location_rank_search := 0;
1784 location_distance := 0;
1785 location_parent := NULL;
1786 -- added ourself as address already
1787 address_havelevel[NEW.rank_address] := true;
1788 --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1790 SELECT * from getNearFeatures(NEW.partition,
1791 CASE WHEN NEW.rank_search >= 26
1792 AND NEW.rank_search < 30
1794 ELSE near_centroid END,
1795 search_maxrank, isin_tokens)
1797 IF location.rank_address != location_rank_search THEN
1798 location_rank_search := location.rank_address;
1799 IF location.isguess THEN
1800 location_distance := location.distance * 1.5;
1802 IF location.rank_address <= 12 THEN
1803 -- for county and above, if we have an area consider that exact
1804 -- (It would be nice to relax the constraint for places close to
1805 -- the boundary but we'd need the exact geometry for that. Too
1807 location_distance = 0;
1809 -- Below county level remain slightly fuzzy.
1810 location_distance := location.distance * 0.5;
1814 CONTINUE WHEN location.keywords <@ location_keywords;
1817 IF location.distance < location_distance OR NOT location.isguess THEN
1818 location_keywords := location.keywords;
1820 location_isaddress := NOT address_havelevel[location.rank_address];
1821 IF location_isaddress AND location.isguess AND location_parent IS NOT NULL THEN
1822 location_isaddress := ST_Contains(location_parent,location.centroid);
1825 -- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
1826 -- Add it to the list of search terms
1827 IF NOT %REVERSE-ONLY% THEN
1828 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1830 INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
1831 VALUES (NEW.place_id, location.place_id, true, location_isaddress, location.distance, location.rank_address);
1833 IF location_isaddress THEN
1834 -- add postcode if we have one
1835 -- (If multiple postcodes are available, we end up with the highest ranking one.)
1836 IF location.postcode is not null THEN
1837 NEW.postcode = location.postcode;
1840 address_havelevel[location.rank_address] := true;
1841 IF NOT location.isguess THEN
1842 SELECT geometry FROM placex WHERE place_id = location.place_id INTO location_parent;
1845 IF location.rank_address > parent_place_id_rank THEN
1846 NEW.parent_place_id = location.place_id;
1847 parent_place_id_rank = location.rank_address;
1852 --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1857 --DEBUG: RAISE WARNING 'address computed';
1859 IF NEW.address is not null AND NEW.address ? 'postcode'
1860 AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
1861 NEW.postcode := upper(trim(NEW.address->'postcode'));
1864 IF NEW.postcode is null AND NEW.rank_search > 8 THEN
1865 NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
1868 -- if we have a name add this to the name search table
1869 IF NEW.name IS NOT NULL THEN
1871 IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
1872 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);
1873 --DEBUG: RAISE WARNING 'added to location (full)';
1876 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1877 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1878 --DEBUG: RAISE WARNING 'insert into road location table (full)';
1881 result := insertSearchName(NEW.partition, NEW.place_id, name_vector,
1882 NEW.rank_search, NEW.rank_address, NEW.geometry);
1883 --DEBUG: RAISE WARNING 'added to search name (full)';
1885 IF NOT %REVERSE-ONLY% THEN
1886 INSERT INTO search_name (place_id, search_rank, address_rank,
1887 importance, country_code, name_vector,
1888 nameaddress_vector, centroid)
1889 VALUES (NEW.place_id, NEW.rank_search, NEW.rank_address,
1890 NEW.importance, NEW.country_code, name_vector,
1891 nameaddress_vector, place_centroid);
1896 -- If we've not managed to pick up a better one - default centroid
1897 IF NEW.centroid IS NULL THEN
1898 NEW.centroid := place_centroid;
1901 --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
1908 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1914 -- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
1916 update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1917 --DEBUG: RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;
1918 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1919 --DEBUG: RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;
1921 IF OLD.rank_address < 30 THEN
1923 -- mark everything linked to this place for re-indexing
1924 --DEBUG: RAISE WARNING 'placex_delete:03 % %',OLD.osm_type,OLD.osm_id;
1925 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1926 and placex.place_id = place_addressline.place_id and indexed_status = 0 and place_addressline.isaddress;
1928 --DEBUG: RAISE WARNING 'placex_delete:04 % %',OLD.osm_type,OLD.osm_id;
1929 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1931 --DEBUG: RAISE WARNING 'placex_delete:05 % %',OLD.osm_type,OLD.osm_id;
1932 b := deleteRoad(OLD.partition, OLD.place_id);
1934 --DEBUG: RAISE WARNING 'placex_delete:06 % %',OLD.osm_type,OLD.osm_id;
1935 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1936 --DEBUG: RAISE WARNING 'placex_delete:07 % %',OLD.osm_type,OLD.osm_id;
1937 -- reparenting also for OSM Interpolation Lines (and for Tiger?)
1938 update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD.place_id;
1942 --DEBUG: RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;
1944 IF OLD.rank_address < 26 THEN
1945 b := deleteLocationArea(OLD.partition, OLD.place_id, OLD.rank_search);
1948 --DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
1950 IF OLD.name is not null THEN
1951 IF NOT %REVERSE-ONLY% THEN
1952 DELETE from search_name WHERE place_id = OLD.place_id;
1954 b := deleteSearchName(OLD.partition, OLD.place_id);
1957 --DEBUG: RAISE WARNING 'placex_delete:10 % %',OLD.osm_type,OLD.osm_id;
1959 DELETE FROM place_addressline where place_id = OLD.place_id;
1961 --DEBUG: RAISE WARNING 'placex_delete:11 % %',OLD.osm_type,OLD.osm_id;
1963 -- remove from tables for special search
1964 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1965 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema() INTO b;
1967 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1970 --DEBUG: RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;
1978 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1984 --DEBUG: RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1986 -- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
1987 IF st_area(OLD.geometry) > 2 and st_isvalid(OLD.geometry) THEN
1988 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;
1990 insert into import_polygon_delete (osm_type, osm_id, class, type) values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1996 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;
1998 -- interpolations are special
1999 IF OLD.osm_type='W' and OLD.class = 'place' and OLD.type = 'houses' THEN
2000 UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD.osm_id; -- osm_id = wayid (=old.osm_id)
2009 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
2014 existingplacex RECORD;
2015 existingline RECORD;
2016 existinggeometry GEOMETRY;
2017 existingplace_id BIGINT;
2022 --DEBUG: RAISE WARNING '-----------------------------------------------------------------------------------';
2023 --DEBUG: RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
2024 -- filter wrong tupels
2025 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
2026 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2027 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
2028 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
2032 -- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2033 IF NEW.class='place' and NEW.type='houses' and NEW.osm_type='W' and ST_GeometryType(NEW.geometry) = 'ST_LineString' THEN
2034 -- Have we already done this place?
2035 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;
2037 -- Get the existing place_id
2038 select * from location_property_osmline where osm_id = NEW.osm_id INTO existingline;
2040 -- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
2041 IF existing.osm_type IS NULL THEN
2042 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2045 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2046 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2048 -- 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)
2049 IF existingline.osm_id IS NOT NULL THEN
2050 delete from location_property_osmline where osm_id = NEW.osm_id;
2053 -- for interpolations invalidate all nodes on the line
2054 update placex p set indexed_status = 2
2055 from planet_osm_ways w
2056 where w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes);
2059 INSERT INTO location_property_osmline (osm_id, address, linegeo)
2060 VALUES (NEW.osm_id, NEW.address, NEW.geometry);
2063 IF existing.osm_type IS NULL THEN
2067 IF coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2068 OR (coalesce(existing.extratags, ''::hstore) != coalesce(NEW.extratags, ''::hstore))
2069 OR existing.geometry::text != NEW.geometry::text
2074 address = NEW.address,
2075 extratags = NEW.extratags,
2076 admin_level = NEW.admin_level,
2077 geometry = NEW.geometry
2078 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2083 ELSE -- insert to placex
2085 -- Patch in additional country names
2086 IF NEW.admin_level = 2 AND NEW.type = 'administrative'
2087 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
2088 SELECT name FROM country_name WHERE country_code = lower(NEW.address->'country') INTO existing;
2089 IF existing.name IS NOT NULL THEN
2090 NEW.name = existing.name || NEW.name;
2094 -- Have we already done this place?
2095 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;
2097 -- Get the existing place_id
2098 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;
2100 -- Handle a place changing type by removing the old data
2101 -- My generated 'place' types are causing havok because they overlap with real keys
2102 -- TODO: move them to their own special purpose key/class to avoid collisions
2103 IF existing.osm_type IS NULL THEN
2104 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class;
2107 --DEBUG: RAISE WARNING 'Existing: %',existing.osm_id;
2108 --DEBUG: RAISE WARNING 'Existing PlaceX: %',existingplacex.place_id;
2111 IF existing.geometry is not null AND st_isvalid(existing.geometry)
2112 AND st_area(existing.geometry) > 0.02
2113 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2114 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
2116 INSERT INTO import_polygon_error (osm_type, osm_id, class, type, name, country_code, updated, errormessage, prevgeometry, newgeometry)
2117 VALUES (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.address->'country', now(),
2118 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
2122 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2123 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
2125 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed
2126 IF existingplacex.osm_type IS NULL OR
2127 (existingplacex.class = 'boundary' AND
2128 ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
2129 (existingplacex.type != NEW.type)))
2132 IF existingplacex.osm_type IS NOT NULL THEN
2133 -- sanity check: ignore admin_level changes on places with too many active children
2134 -- or we end up reindexing entire countries because somebody accidentally deleted admin_level
2135 --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;
2136 --LIMIT INDEXING: IF i > 100000 THEN
2137 --LIMIT INDEXING: RETURN null;
2138 --LIMIT INDEXING: END IF;
2141 IF existing.osm_type IS NOT NULL THEN
2142 -- pathological case caused by the triggerless copy into place during initial import
2143 -- force delete even for large areas, it will be reinserted later
2144 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;
2145 DELETE from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2148 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
2149 insert into placex (osm_type, osm_id, class, type, name,
2150 admin_level, address, extratags, geometry)
2151 values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name,
2152 NEW.admin_level, NEW.address, NEW.extratags, NEW.geometry);
2154 --DEBUG: RAISE WARNING 'insert done % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,NEW.name;
2159 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
2160 IF existing.geometry::text != NEW.geometry::text
2161 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
2162 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
2165 -- Get the version of the geometry actually used (in placex table)
2166 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;
2168 -- Performance limit
2169 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
2171 -- 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
2172 update placex set indexed_status = 2 where indexed_status = 0 and
2173 (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2174 AND NOT (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2175 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2177 update placex set indexed_status = 2 where indexed_status = 0 and
2178 (st_covers(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
2179 AND NOT (st_covers(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
2180 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
2187 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
2188 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
2189 OR coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2190 OR coalesce(existing.admin_level, 15) != coalesce(NEW.admin_level, 15)
2191 OR existing.geometry::text != NEW.geometry::text
2196 address = NEW.address,
2197 extratags = NEW.extratags,
2198 admin_level = NEW.admin_level,
2199 geometry = NEW.geometry
2200 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2203 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
2204 IF NEW.address is NULL OR NOT NEW.address ? 'postcode' THEN
2205 -- postcode was deleted, no longer retain in placex
2206 DELETE FROM placex where place_id = existingplacex.place_id;
2210 NEW.name := hstore('ref', NEW.address->'postcode');
2213 IF NEW.class in ('boundary')
2214 AND ST_GeometryType(NEW.geometry) not in ('ST_Polygon','ST_MultiPolygon') THEN
2215 DELETE FROM placex where place_id = existingplacex.place_id;
2221 address = NEW.address,
2222 parent_place_id = null,
2223 extratags = NEW.extratags,
2224 admin_level = NEW.admin_level,
2226 geometry = NEW.geometry
2227 where place_id = existingplacex.place_id;
2228 -- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
2229 -- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2231 and (coalesce(existing.address, ''::hstore) != coalesce(NEW.address, ''::hstore)
2232 or existing.geometry::text != NEW.geometry::text)
2234 result:= osmline_reinsert(NEW.osm_id, NEW.geometry);
2237 -- linked places should get potential new naming and addresses
2238 IF existingplacex.linked_place_id is not NULL THEN
2241 extratags = p.extratags,
2244 where x.place_id = existingplacex.linked_place_id
2245 and x.indexed_status = 0
2246 and x.osm_type = p.osm_type
2247 and x.osm_id = p.osm_id
2248 and x.class = p.class;
2253 -- Abort the add (we modified the existing place instead)
2258 $$ LANGUAGE plpgsql;
2261 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2266 IF name is null THEN
2270 FOR j IN 1..array_upper(languagepref,1) LOOP
2271 IF name ? languagepref[j] THEN
2272 result := trim(name->languagepref[j]);
2273 IF result != '' THEN
2279 -- anything will do as a fallback - just take the first name type thing there is
2280 RETURN trim((avals(name))[1]);
2283 LANGUAGE plpgsql IMMUTABLE;
2285 --housenumber only needed for tiger data
2286 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
2298 FOR location IN select * from get_addressdata(for_place_id, housenumber) where isaddress order by rank_address desc LOOP
2299 currresult := trim(get_name_by_language(location.name, languagepref));
2300 IF currresult != prevresult AND currresult IS NOT NULL AND result[(100 - location.rank_address)] IS NULL THEN
2301 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2302 prevresult := currresult;
2306 RETURN array_to_string(result,', ');
2311 DROP TYPE IF EXISTS addressline CASCADE;
2312 create type addressline as (
2319 admin_level INTEGER,
2322 rank_address INTEGER,
2326 -- Compute the list of address parts for the given place.
2328 -- If in_housenumber is greator or equal 0, look for an interpolation.
2329 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
2332 for_place_id BIGINT;
2337 countrylocation RECORD;
2338 searchcountrycode varchar(2);
2339 searchhousenumber TEXT;
2340 searchhousename HSTORE;
2341 searchrankaddress INTEGER;
2342 searchpostcode TEXT;
2343 postcode_isaddress BOOL;
2348 -- The place ein question might not have a direct entry in place_addressline.
2349 -- Look for the parent of such places then and save if in for_place_id.
2351 postcode_isaddress := true;
2353 -- first query osmline (interpolation lines)
2354 IF in_housenumber >= 0 THEN
2355 SELECT parent_place_id, country_code, in_housenumber::text, 30, postcode,
2356 null, 'place', 'house'
2357 FROM location_property_osmline
2358 WHERE place_id = in_place_id AND in_housenumber>=startnumber
2359 AND in_housenumber <= endnumber
2360 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2361 searchpostcode, searchhousename, searchclass, searchtype;
2364 --then query tiger data
2365 -- %NOTIGERDATA% IF 0 THEN
2366 IF for_place_id IS NULL AND in_housenumber >= 0 THEN
2367 SELECT parent_place_id, 'us', in_housenumber::text, 30, postcode, null,
2369 FROM location_property_tiger
2370 WHERE place_id = in_place_id AND in_housenumber >= startnumber
2371 AND in_housenumber <= endnumber
2372 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2373 searchpostcode, searchhousename, searchclass, searchtype;
2375 -- %NOTIGERDATA% END IF;
2377 -- %NOAUXDATA% IF 0 THEN
2378 IF for_place_id IS NULL THEN
2379 SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
2380 FROM location_property_aux
2381 WHERE place_id = in_place_id
2382 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
2383 searchpostcode, searchhousename, searchclass, searchtype;
2385 -- %NOAUXDATA% END IF;
2388 IF for_place_id IS NULL THEN
2389 SELECT parent_place_id, country_code, rank_address, postcode, 'place', 'postcode'
2390 FROM location_postcode
2391 WHERE place_id = in_place_id
2392 INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
2393 searchclass, searchtype;
2396 -- POI objects in the placex table
2397 IF for_place_id IS NULL THEN
2398 SELECT parent_place_id, country_code, housenumber, rank_search, postcode,
2401 WHERE place_id = in_place_id and rank_search > 27
2402 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress,
2403 searchpostcode, searchhousename, searchclass, searchtype;
2406 -- If for_place_id is still NULL at this point then the object has its own
2407 -- entry in place_address line. However, still check if there is not linked
2408 -- place we should be using instead.
2409 IF for_place_id IS NULL THEN
2410 select coalesce(linked_place_id, place_id), country_code,
2411 housenumber, rank_search, postcode, null
2412 from placex where place_id = in_place_id
2413 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2416 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2418 found := 1000; -- the lowest rank_address included
2420 -- Return the record for the base entry.
2422 SELECT placex.place_id, osm_type, osm_id, name,
2423 class, type, admin_level,
2424 type not in ('postcode', 'postal_code') as isaddress,
2425 CASE WHEN rank_address = 0 THEN 100
2426 WHEN rank_address = 11 THEN 5
2427 ELSE rank_address END as rank_address,
2428 0 as distance, country_code, postcode
2430 WHERE place_id = for_place_id
2432 --RAISE WARNING '%',location;
2433 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2434 searchcountrycode := location.country_code;
2436 IF location.rank_address < 4 THEN
2437 -- no country locations for ranks higher than country
2438 searchcountrycode := NULL;
2440 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2441 location.name, location.class, location.type,
2442 location.admin_level, true, location.isaddress,
2443 location.rank_address, location.distance)::addressline;
2444 RETURN NEXT countrylocation;
2445 found := location.rank_address;
2449 SELECT placex.place_id, osm_type, osm_id, name,
2450 CASE WHEN extratags ? 'place' THEN 'place' ELSE class END as class,
2451 CASE WHEN extratags ? 'place' THEN extratags->'place' ELSE type END as type,
2452 admin_level, fromarea, isaddress,
2453 CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2454 distance, country_code, postcode
2455 FROM place_addressline join placex on (address_place_id = placex.place_id)
2456 WHERE place_addressline.place_id = for_place_id
2457 AND (cached_rank_address >= 4 AND cached_rank_address < searchrankaddress)
2458 AND linked_place_id is null
2459 AND (placex.country_code IS NULL OR searchcountrycode IS NULL
2460 OR placex.country_code = searchcountrycode)
2461 ORDER BY rank_address desc, isaddress desc, fromarea desc,
2462 distance asc, rank_search desc
2464 --RAISE WARNING '%',location;
2465 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2466 searchcountrycode := location.country_code;
2468 IF location.type in ('postcode', 'postal_code') THEN
2469 postcode_isaddress := false;
2470 IF location.osm_type != 'R' THEN
2471 location.isaddress := FALSE;
2474 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id,
2475 location.name, location.class, location.type,
2476 location.admin_level, location.fromarea,
2477 location.isaddress, location.rank_address,
2478 location.distance)::addressline;
2479 RETURN NEXT countrylocation;
2480 found := location.rank_address;
2483 -- If no country was included yet, add the name information from country_name.
2485 SELECT name FROM country_name
2486 WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
2487 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2488 IF countryname IS NOT NULL THEN
2489 location := ROW(null, null, null, countryname, 'place', 'country',
2490 null, true, true, 4, 0)::addressline;
2491 RETURN NEXT location;
2495 -- Finally add some artificial rows.
2496 IF searchcountrycode IS NOT NULL THEN
2497 location := ROW(null, null, null, hstore('ref', searchcountrycode),
2498 'place', 'country_code', null, true, false, 4, 0)::addressline;
2499 RETURN NEXT location;
2502 IF searchhousename IS NOT NULL THEN
2503 location := ROW(in_place_id, null, null, searchhousename, searchclass,
2504 searchtype, null, true, true, 29, 0)::addressline;
2505 RETURN NEXT location;
2508 IF searchhousenumber IS NOT NULL THEN
2509 location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber),
2510 'place', 'house_number', null, true, true, 28, 0)::addressline;
2511 RETURN NEXT location;
2514 IF searchpostcode IS NOT NULL THEN
2515 location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
2516 'postcode', null, false, postcode_isaddress, 5, 0)::addressline;
2517 RETURN NEXT location;
2526 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2527 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2532 place_centroid GEOMETRY;
2533 out_partition INTEGER;
2534 out_parent_place_id BIGINT;
2536 address_street_word_id INTEGER;
2541 place_centroid := ST_Centroid(pointgeo);
2542 out_partition := get_partition(in_countrycode);
2543 out_parent_place_id := null;
2545 address_street_word_id := get_name_id(make_standard_name(in_street));
2546 IF address_street_word_id IS NOT NULL THEN
2547 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2548 out_parent_place_id := location.place_id;
2552 IF out_parent_place_id IS NULL THEN
2553 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2554 out_parent_place_id := location.place_id;
2558 out_postcode := in_postcode;
2559 IF out_postcode IS NULL THEN
2560 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2562 -- XXX look into postcode table
2565 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2566 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2567 newpoints := newpoints + 1;
2574 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2581 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2582 IF members[i+1] = member THEN
2583 result := result || members[i];
2592 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2598 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2599 IF members[i+1] = ANY(memberLabels) THEN
2600 RETURN NEXT members[i];
2609 -- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
2610 CREATE OR REPLACE FUNCTION decode_url_part(p varchar) RETURNS varchar
2612 SELECT convert_from(CAST(E'\\x' || array_to_string(ARRAY(
2613 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
2614 FROM regexp_matches($1, '%[0-9a-f][0-9a-f]|.', 'gi') AS r(m)
2615 ), '') AS bytea), 'UTF8');
2617 LANGUAGE SQL IMMUTABLE STRICT;
2619 CREATE OR REPLACE FUNCTION catch_decode_url_part(p varchar) RETURNS varchar
2623 RETURN decode_url_part(p);
2625 WHEN others THEN return null;
2628 LANGUAGE plpgsql IMMUTABLE;
2630 DROP TYPE wikipedia_article_match CASCADE;
2631 create type wikipedia_article_match as (
2637 CREATE OR REPLACE FUNCTION get_wikipedia_match(extratags HSTORE, country_code varchar(2)) RETURNS wikipedia_article_match
2643 wiki_article_title TEXT;
2644 wiki_article_language TEXT;
2645 result wikipedia_article_match;
2647 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'];
2649 WHILE langs[i] IS NOT NULL LOOP
2650 wiki_article := extratags->(case when langs[i] in ('english','country') THEN 'wikipedia' ELSE 'wikipedia:'||langs[i] END);
2651 IF wiki_article is not null THEN
2652 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/wiki/',E'\\2:');
2653 wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title=',E'\\2:');
2654 wiki_article := regexp_replace(wiki_article,E'^(.*?)/([a-z]{2,3})/wiki/',E'\\2:');
2655 --wiki_article := regexp_replace(wiki_article,E'^(.*?)([a-z]{2,3})[=:]',E'\\2:');
2656 wiki_article := replace(wiki_article,' ','_');
2657 IF strpos(wiki_article, ':') IN (3,4) THEN
2658 wiki_article_language := lower(trim(split_part(wiki_article, ':', 1)));
2659 wiki_article_title := trim(substr(wiki_article, strpos(wiki_article, ':')+1));
2661 wiki_article_title := trim(wiki_article);
2662 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;
2665 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2666 from wikipedia_article
2667 where language = wiki_article_language and
2668 (title = wiki_article_title OR title = catch_decode_url_part(wiki_article_title) OR title = replace(catch_decode_url_part(wiki_article_title),E'\\',''))
2670 select wikipedia_article.language,wikipedia_article.title,wikipedia_article.importance
2671 from wikipedia_redirect join wikipedia_article on (wikipedia_redirect.language = wikipedia_article.language and wikipedia_redirect.to_title = wikipedia_article.title)
2672 where wikipedia_redirect.language = wiki_article_language and
2673 (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'\\',''))
2674 order by importance desc limit 1 INTO result;
2676 IF result.language is not null THEN
2687 CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
2688 RETURNS SETOF GEOMETRY
2702 remainingdepth INTEGER;
2707 -- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
2709 IF (ST_GeometryType(geometry) not in ('ST_Polygon','ST_MultiPolygon') OR NOT ST_IsValid(geometry)) THEN
2710 RETURN NEXT geometry;
2714 remainingdepth := maxdepth - 1;
2715 area := ST_AREA(geometry);
2716 IF remainingdepth < 1 OR area < maxarea THEN
2717 RETURN NEXT geometry;
2721 xmin := st_xmin(geometry);
2722 xmax := st_xmax(geometry);
2723 ymin := st_ymin(geometry);
2724 ymax := st_ymax(geometry);
2725 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(ymin,xmin),ST_Point(ymax,xmax)),4326);
2727 -- if the geometry completely covers the box don't bother to slice any more
2728 IF ST_AREA(secbox) = area THEN
2729 RETURN NEXT geometry;
2733 xmid := (xmin+xmax)/2;
2734 ymid := (ymin+ymax)/2;
2737 FOR seg IN 1..4 LOOP
2740 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymin),ST_Point(xmid,ymid)),4326);
2743 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmin,ymid),ST_Point(xmid,ymax)),4326);
2746 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymin),ST_Point(xmax,ymid)),4326);
2749 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(xmid,ymid),ST_Point(xmax,ymax)),4326);
2752 IF st_intersects(geometry, secbox) THEN
2753 secgeo := st_intersection(geometry, secbox);
2754 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
2755 FOR geo IN select quad_split_geometry(secgeo, maxarea, remainingdepth) as geom LOOP
2756 IF NOT ST_IsEmpty(geo.geom) AND ST_GeometryType(geo.geom) in ('ST_Polygon','ST_MultiPolygon') THEN
2758 RETURN NEXT geo.geom;
2770 CREATE OR REPLACE FUNCTION split_geometry(geometry GEOMETRY)
2771 RETURNS SETOF GEOMETRY
2776 -- 10000000000 is ~~ 1x1 degree
2777 FOR geo IN select quad_split_geometry(geometry, 0.25, 20) as geom LOOP
2778 RETURN NEXT geo.geom;
2786 CREATE OR REPLACE FUNCTION place_force_delete(placeid BIGINT) RETURNS BOOLEAN
2790 osmtype character(1);
2794 SELECT osm_type, osm_id, class, type FROM placex WHERE place_id = placeid INTO osmtype, osmid, pclass, ptype;
2795 DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2796 DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2797 -- force delete from place/placex by making it a very small geometry
2798 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;
2799 DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype;
2806 CREATE OR REPLACE FUNCTION place_force_update(placeid BIGINT) RETURNS BOOLEAN
2814 UPDATE placex SET indexed_status = 2 WHERE place_id = placeid;
2815 SELECT geometry, rank_search FROM placex WHERE place_id = placeid INTO placegeom, rank;
2816 IF placegeom IS NOT NULL AND ST_IsValid(placegeom) THEN
2817 IF ST_GeometryType(placegeom) in ('ST_Polygon','ST_MultiPolygon') THEN
2818 FOR geom IN select split_geometry(placegeom) FROM placex WHERE place_id = placeid LOOP
2819 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2820 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'));
2821 update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
2822 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'));
2828 ELSEIF rank < 18 THEN
2830 ELSEIF rank < 20 THEN
2832 ELSEIF rank = 21 THEN
2834 ELSEIF rank < 24 THEN
2836 ELSEIF rank < 26 THEN
2837 diameter := 0.002; -- 100 to 200 meters
2838 ELSEIF rank < 28 THEN
2839 diameter := 0.001; -- 50 to 100 meters
2841 IF diameter > 0 THEN
2843 -- roads may cause reparenting for >27 rank places
2844 update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin(placex.geometry, placegeom, diameter);
2845 ELSEIF rank >= 16 THEN
2846 -- up to rank 16, street-less addresses may need reparenting
2847 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');
2849 -- for all other places the search terms may change as well
2850 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);