1 --DROP TRIGGER IF EXISTS place_before_insert on placex;
2 --DROP TRIGGER IF EXISTS place_before_update on placex;
3 --CREATE TYPE addresscalculationtype AS (
9 CREATE OR REPLACE FUNCTION getclasstypekey(c text, t text) RETURNS TEXT
16 LANGUAGE plpgsql IMMUTABLE;
18 CREATE OR REPLACE FUNCTION isbrokengeometry(place geometry) RETURNS BOOLEAN
24 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
30 LANGUAGE plpgsql IMMUTABLE;
32 CREATE OR REPLACE FUNCTION clean_geometry(place geometry) RETURNS geometry
38 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
39 NEWgeometry := ST_buffer(NEWgeometry,0);
40 IF ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
41 RETURN ST_SetSRID(ST_Point(0,0),4326);
47 LANGUAGE plpgsql IMMUTABLE;
49 CREATE OR REPLACE FUNCTION geometry_sector(partition INTEGER, place geometry) RETURNS INTEGER
54 -- RAISE WARNING '%',place;
56 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
57 NEWgeometry := ST_buffer(NEWgeometry,0);
58 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
62 RETURN (partition*1000000) + (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
65 LANGUAGE plpgsql IMMUTABLE;
67 CREATE OR REPLACE FUNCTION debug_geometry_sector(osmid integer, place geometry) RETURNS INTEGER
72 -- RAISE WARNING '%',osmid;
77 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
78 NEWgeometry := ST_buffer(NEWgeometry,0);
79 IF ST_IsEmpty(NEWgeometry) OR NOT ST_IsValid(NEWgeometry) OR ST_X(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') OR ST_Y(ST_Centroid(NEWgeometry))::text in ('NaN','Infinity','-Infinity') THEN
83 RETURN (500-ST_X(ST_Centroid(NEWgeometry))::integer)*1000 + (500-ST_Y(ST_Centroid(NEWgeometry))::integer);
86 LANGUAGE plpgsql IMMUTABLE;
88 CREATE OR REPLACE FUNCTION transliteration(text) RETURNS text
89 AS '{modulepath}/nominatim.so', 'transliteration'
90 LANGUAGE c IMMUTABLE STRICT;
92 CREATE OR REPLACE FUNCTION gettokenstring(text) RETURNS text
93 AS '{modulepath}/nominatim.so', 'gettokenstring'
94 LANGUAGE c IMMUTABLE STRICT;
96 CREATE OR REPLACE FUNCTION make_standard_name(name TEXT) RETURNS TEXT
101 o := gettokenstring(transliteration(name));
102 RETURN trim(substr(o,1,length(o)));
105 LANGUAGE 'plpgsql' IMMUTABLE;
107 CREATE OR REPLACE FUNCTION getorcreate_word_id(lookup_word TEXT)
112 return_word_id INTEGER;
114 lookup_token := trim(lookup_word);
115 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
116 IF return_word_id IS NULL THEN
117 return_word_id := nextval('seq_word');
118 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), null, null, null, null, 0, null);
120 RETURN return_word_id;
125 CREATE OR REPLACE FUNCTION getorcreate_housenumber_id(lookup_word TEXT)
130 return_word_id INTEGER;
132 lookup_token := ' '||trim(lookup_word);
133 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class='place' and type='house' into return_word_id;
134 IF return_word_id IS NULL THEN
135 return_word_id := nextval('seq_word');
136 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, 'place', 'house', null, 0, null);
138 RETURN return_word_id;
143 CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
148 return_word_id INTEGER;
150 lookup_token := ' '||trim(lookup_word);
151 SELECT min(word_id) FROM word WHERE word_token = lookup_token and country_code=lookup_country_code into return_word_id;
152 IF return_word_id IS NULL THEN
153 return_word_id := nextval('seq_word');
154 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, lookup_country_code, 0, null);
156 RETURN return_word_id;
161 CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type 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=lookup_class and type = lookup_type 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, null, null, lookup_class, lookup_type, null, 0, null);
174 RETURN return_word_id;
179 CREATE OR REPLACE FUNCTION getorcreate_tagpair(lookup_class text, lookup_type text)
184 return_word_id INTEGER;
186 lookup_token := lookup_class||'='||lookup_type;
187 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
188 IF return_word_id IS NULL THEN
189 return_word_id := nextval('seq_word');
190 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, null, null, null, 0, null);
192 RETURN return_word_id;
197 CREATE OR REPLACE FUNCTION get_tagpair(lookup_class text, lookup_type text)
202 return_word_id INTEGER;
204 lookup_token := lookup_class||'='||lookup_type;
205 SELECT min(word_id) FROM word WHERE word_token = lookup_token into return_word_id;
206 RETURN return_word_id;
211 CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
216 return_word_id INTEGER;
218 lookup_token := ' '||trim(lookup_word);
219 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
220 IF return_word_id IS NULL THEN
221 return_word_id := nextval('seq_word');
222 INSERT INTO word VALUES (return_word_id, lookup_token, null, null, lookup_class, lookup_type, null, 0, op, null);
224 RETURN return_word_id;
229 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT, src_word TEXT)
234 nospace_lookup_token TEXT;
235 return_word_id INTEGER;
237 lookup_token := ' '||trim(lookup_word);
238 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
239 IF return_word_id IS NULL THEN
240 return_word_id := nextval('seq_word');
241 INSERT INTO word VALUES (return_word_id, lookup_token, regexp_replace(lookup_token,E'([^0-9])\\1+',E'\\1','g'), src_word, null, null, null, 0, null);
242 -- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
243 -- IF ' '||nospace_lookup_token != lookup_token THEN
244 -- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
247 RETURN return_word_id;
252 CREATE OR REPLACE FUNCTION getorcreate_name_id(lookup_word TEXT)
257 RETURN getorcreate_name_id(lookup_word, '');
262 CREATE OR REPLACE FUNCTION get_word_id(lookup_word TEXT)
267 return_word_id INTEGER;
269 lookup_token := trim(lookup_word);
270 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
271 RETURN return_word_id;
274 LANGUAGE plpgsql IMMUTABLE;
276 CREATE OR REPLACE FUNCTION get_name_id(lookup_word TEXT)
281 return_word_id INTEGER;
283 lookup_token := ' '||trim(lookup_word);
284 SELECT min(word_id) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id;
285 RETURN return_word_id;
288 LANGUAGE plpgsql IMMUTABLE;
290 CREATE OR REPLACE FUNCTION array_merge(a INTEGER[], b INTEGER[])
297 IF array_upper(a, 1) IS NULL THEN
300 IF array_upper(b, 1) IS NULL THEN
304 FOR i IN 1..array_upper(b, 1) LOOP
305 IF NOT (ARRAY[b[i]] <@ r) THEN
312 LANGUAGE plpgsql IMMUTABLE;
314 CREATE OR REPLACE FUNCTION make_keywords(src HSTORE) RETURNS INTEGER[]
324 result := '{}'::INTEGER[];
326 FOR item IN SELECT (each(src)).* LOOP
328 s := make_standard_name(item.value);
330 w := getorcreate_name_id(s, item.value);
332 IF not(ARRAY[w] <@ result) THEN
333 result := result || w;
336 words := string_to_array(s, ' ');
337 IF array_upper(words, 1) IS NOT NULL THEN
338 FOR j IN 1..array_upper(words, 1) LOOP
339 IF (words[j] != '') THEN
340 w = getorcreate_word_id(words[j]);
341 IF NOT (ARRAY[w] <@ result) THEN
342 result := result || w;
348 words := regexp_split_to_array(item.value, E'[,;()]');
349 IF array_upper(words, 1) != 1 THEN
350 FOR j IN 1..array_upper(words, 1) LOOP
351 s := make_standard_name(words[j]);
353 w := getorcreate_word_id(s);
354 IF NOT (ARRAY[w] <@ result) THEN
355 result := result || w;
361 s := regexp_replace(item.value, '市$', '');
362 IF s != item.value THEN
363 s := make_standard_name(s);
365 w := getorcreate_name_id(s, item.value);
366 IF NOT (ARRAY[w] <@ result) THEN
367 result := result || w;
377 LANGUAGE plpgsql IMMUTABLE;
379 CREATE OR REPLACE FUNCTION make_keywords(src TEXT) RETURNS INTEGER[]
389 result := '{}'::INTEGER[];
391 s := make_standard_name(src);
392 w := getorcreate_name_id(s);
394 IF NOT (ARRAY[w] <@ result) THEN
395 result := result || w;
398 words := string_to_array(s, ' ');
399 IF array_upper(words, 1) IS NOT NULL THEN
400 FOR j IN 1..array_upper(words, 1) LOOP
401 IF (words[j] != '') THEN
402 w = getorcreate_word_id(words[j]);
403 IF NOT (ARRAY[w] <@ result) THEN
404 result := result || w;
413 LANGUAGE plpgsql IMMUTABLE;
415 CREATE OR REPLACE FUNCTION get_word_score(wordscores wordscore[], words text[]) RETURNS integer
422 IF (wordscores is null OR words is null) THEN
427 FOR idxword in 1 .. array_upper(words, 1) LOOP
428 FOR idxscores in 1 .. array_upper(wordscores, 1) LOOP
429 IF wordscores[idxscores].word = words[idxword] THEN
430 result := result + wordscores[idxscores].score;
438 LANGUAGE plpgsql IMMUTABLE;
440 CREATE OR REPLACE FUNCTION get_country_code(place geometry) RETURNS TEXT
443 place_centre GEOMETRY;
446 place_centre := ST_Centroid(place);
448 --RAISE WARNING 'start: %', ST_AsText(place_centre);
450 -- Try for a OSM polygon first
451 FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_contains(geometry, place_centre) limit 1
453 RETURN nearcountry.country_code;
456 --RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
458 -- Try for OSM fallback data
459 FOR nearcountry IN select country_code from country_osm_grid where st_contains(geometry, place_centre) limit 1
461 RETURN nearcountry.country_code;
464 --RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
466 -- Natural earth data (first fallback)
467 FOR nearcountry IN select country_code from country_naturalearthdata where st_contains(geometry, place_centre) limit 1
469 RETURN nearcountry.country_code;
472 -- Natural earth data (first fallback)
473 FOR nearcountry IN select country_code from country_naturalearthdata where st_distance(geometry, place_centre) < 0.5 limit 1
475 RETURN nearcountry.country_code;
478 --RAISE WARNING 'in country: %', ST_AsText(place_centre);
480 -- WorldBoundaries data (second fallback - think there might be something broken in this data)
481 FOR nearcountry IN select country_code from country where st_contains(geometry, place_centre) limit 1
483 RETURN nearcountry.country_code;
486 --RAISE WARNING 'near country: %', ST_AsText(place_centre);
488 -- Still not in a country - try nearest within ~12 miles of a country
489 FOR nearcountry IN select country_code from country where st_distance(geometry, place_centre) < 0.5
490 order by st_distance(geometry, place) limit 1
492 RETURN nearcountry.country_code;
498 LANGUAGE plpgsql IMMUTABLE;
500 CREATE OR REPLACE FUNCTION get_country_code(place geometry, in_country_code VARCHAR(2)) RETURNS TEXT
505 FOR nearcountry IN select country_code from country_name where country_code = lower(in_country_code)
507 RETURN nearcountry.country_code;
509 RETURN get_country_code(place);
512 LANGUAGE plpgsql IMMUTABLE;
514 CREATE OR REPLACE FUNCTION get_country_language_code(search_country_code VARCHAR(2)) RETURNS TEXT
519 FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
521 RETURN lower(nearcountry.country_default_language_code);
526 LANGUAGE plpgsql IMMUTABLE;
528 CREATE OR REPLACE FUNCTION get_partition(place geometry, in_country_code VARCHAR(10)) RETURNS INTEGER
531 place_centre GEOMETRY;
534 FOR nearcountry IN select partition from country_name where country_code = in_country_code
536 RETURN nearcountry.partition;
541 LANGUAGE plpgsql IMMUTABLE;
543 CREATE OR REPLACE FUNCTION delete_location(OLD_place_id BIGINT) RETURNS BOOLEAN
547 DELETE FROM location_area where place_id = OLD_place_id;
548 -- TODO:location_area
554 CREATE OR REPLACE FUNCTION add_location(
556 country_code varchar(2),
560 rank_address INTEGER,
581 IF rank_search > 25 THEN
582 RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
585 -- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
587 x := deleteLocationArea(partition, place_id);
590 IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
593 centroid := ST_Centroid(geometry);
595 xmin := floor(st_xmin(geometry));
596 xmax := ceil(st_xmax(geometry));
597 ymin := floor(st_ymin(geometry));
598 ymax := ceil(st_ymax(geometry));
600 IF xmin = xmax OR ymin = ymax OR (xmax-xmin < 2 AND ymax-ymin < 2) THEN
601 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, geometry);
603 -- RAISE WARNING 'Spliting geometry: % to %, % to %', xmin, xmax, ymin, ymax;
604 FOR lon IN xmin..(xmax-1) LOOP
605 FOR lat IN ymin..(ymax-1) LOOP
606 secbox := ST_SetSRID(ST_MakeBox2D(ST_Point(lon,lat),ST_Point(lon+1,lat+1)),4326);
607 IF st_intersects(geometry, secbox) THEN
608 secgeo := st_intersection(geometry, secbox);
609 IF NOT ST_IsEmpty(secgeo) AND ST_GeometryType(secgeo) in ('ST_Polygon','ST_MultiPolygon') THEN
610 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
617 ELSEIF rank_search < 26 THEN
620 IF rank_address = 0 THEN
622 ELSEIF rank_search <= 14 THEN
624 ELSEIF rank_search <= 15 THEN
626 ELSEIF rank_search <= 16 THEN
628 ELSEIF rank_search <= 17 THEN
630 ELSEIF rank_search <= 21 THEN
632 ELSEIF rank_search = 25 THEN
636 -- RAISE WARNING 'adding % diameter %', place_id, diameter;
638 secgeo := ST_Buffer(geometry, diameter);
639 x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
644 secgeo := ST_Buffer(geometry, 0.0002);
645 x := insertLocationAreaRoadNear(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
648 secgeo := ST_Buffer(geometry, 0.001);
649 x := insertLocationAreaRoadFar(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
658 CREATE OR REPLACE FUNCTION update_location(
661 place_country_code varchar(2),
664 rank_address INTEGER,
672 b := deleteLocationArea(partition, place_id);
673 -- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
674 RETURN add_location(place_id, place_country_code, name, rank_search, rank_address, geometry);
679 CREATE OR REPLACE FUNCTION search_name_add_words(parent_place_id BIGINT, to_add INTEGER[])
690 -- this should just be an update, but it seems to do insane things to the index size (delete and insert doesn't)
691 FOR childplace IN select * from search_name,place_addressline
692 where address_place_id = parent_place_id
693 and search_name.place_id = place_addressline.place_id
695 delete from search_name where place_id = childplace.place_id;
696 IF not (ARRAY[to_add] <@ childplace.nameaddress_vector) THEN
697 childplace.nameaddress_vector := childplace.nameaddress_vector || to_add;
699 IF childplace.place_id = parent_place_id and not (ARRAY[to_add] <@ childplace.name_vector) THEN
700 childplace.name_vector := childplace.name_vector || to_add;
702 insert into search_name (place_id, search_rank, address_rank, country_code, name_vector, nameaddress_vector, centroid)
703 values (childplace.place_id, childplace.search_rank, childplace.address_rank, childplace.country_code,
704 childplace.name_vector, childplace.nameaddress_vector, childplace.centroid);
712 CREATE OR REPLACE FUNCTION update_location_nameonly(partition INTEGER, OLD_place_id BIGINT, name hstore) RETURNS BOOLEAN
715 newkeywords INTEGER[];
716 addedkeywords INTEGER[];
717 removedkeywords INTEGER[];
721 newkeywords := make_keywords(name);
722 select coalesce(newkeywords,'{}'::INTEGER[]) - coalesce(location_point.keywords,'{}'::INTEGER[]),
723 coalesce(location_point.keywords,'{}'::INTEGER[]) - coalesce(newkeywords,'{}'::INTEGER[]) from location_point
724 where place_id = OLD_place_id into addedkeywords, removedkeywords;
726 -- RAISE WARNING 'update_location_nameonly for %: new:% added:% removed:%', OLD_place_id, newkeywords, addedkeywords, removedkeywords;
728 IF #removedkeywords > 0 THEN
729 -- abort due to tokens removed
733 IF #addedkeywords > 0 THEN
734 -- short circuit - no changes
738 UPDATE location_area set keywords = newkeywords where place_id = OLD_place_id;
739 RETURN search_name_add_words(OLD_place_id, addedkeywords);
745 CREATE OR REPLACE FUNCTION create_interpolation(wayid INTEGER, interpolationtype TEXT) RETURNS INTEGER
757 orginalstartnumber INTEGER;
758 originalnumberrange INTEGER;
761 search_place_id BIGINT;
764 havefirstpoint BOOLEAN;
768 IF interpolationtype = 'odd' OR interpolationtype = 'even' OR interpolationtype = 'all' THEN
770 select postcode from placex where osm_type = 'W' and osm_id = wayid INTO defpostalcode;
771 select nodes from planet_osm_ways where id = wayid INTO waynodes;
772 --RAISE WARNING 'interpolation % % %',wayid,interpolationtype,waynodes;
773 IF array_upper(waynodes, 1) IS NOT NULL THEN
775 havefirstpoint := false;
777 FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
779 select min(place_id) from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' INTO search_place_id;
780 IF search_place_id IS NULL THEN
781 -- null record of right type
782 select * from placex where osm_type = 'N' and osm_id = waynodes[nodeidpos]::INTEGER and type = 'house' limit 1 INTO nextnode;
783 select ST_SetSRID(ST_Point(lon::float/10000000,lat::float/10000000),4326) from planet_osm_nodes where id = waynodes[nodeidpos] INTO nextnode.geometry;
785 select * from placex where place_id = search_place_id INTO nextnode;
788 --RAISE WARNING 'interpolation node % % % ',nextnode.housenumber,ST_X(nextnode.geometry),ST_Y(nextnode.geometry);
790 IF havefirstpoint THEN
792 -- add point to the line string
793 linestr := linestr||','||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
794 endnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
796 IF startnumber IS NOT NULL and startnumber > 0 AND endnumber IS NOT NULL and endnumber > 0 AND @(startnumber - endnumber) < 1000 THEN
798 --RAISE WARNING 'interpolation end % % ',nextnode.place_id,endnumber;
800 IF startnumber != endnumber THEN
802 linestr := linestr || ')';
803 --RAISE WARNING 'linestr %',linestr;
804 linegeo := ST_GeomFromText(linestr,4326);
805 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
806 IF (startnumber > endnumber) THEN
807 housenum := endnumber;
808 endnumber := startnumber;
809 startnumber := housenum;
810 linegeo := ST_Reverse(linegeo);
812 orginalstartnumber := startnumber;
813 originalnumberrange := endnumber - startnumber;
815 -- Too much broken data worldwide for this test to be worth using
816 -- IF originalnumberrange > 500 THEN
817 -- RAISE WARNING 'Number block of % while processing % %', originalnumberrange, prevnode, nextnode;
820 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
821 startnumber := startnumber + 1;
824 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
825 startnumber := startnumber + 2;
827 ELSE -- everything else assumed to be 'all'
828 startnumber := startnumber + 1;
832 endnumber := endnumber - 1;
833 delete from placex where osm_type = 'N' and osm_id = prevnode.osm_id and type = 'house' and place_id != prevnode.place_id;
834 FOR housenum IN startnumber..endnumber BY stepsize LOOP
835 -- this should really copy postcodes but it puts a huge burdon on the system for no big benefit
836 -- ideally postcodes should move up to the way
837 insert into placex (osm_type, osm_id, class, type, admin_level, housenumber, street, isin, postcode,
838 country_code, parent_place_id, rank_address, rank_search, indexed_status, geometry)
839 values ('N',prevnode.osm_id, prevnode.class, prevnode.type, prevnode.admin_level, housenum, prevnode.street, prevnode.isin, coalesce(prevnode.postcode, defpostalcode),
840 prevnode.country_code, prevnode.parent_place_id, prevnode.rank_address, prevnode.rank_search, 1, ST_Line_Interpolate_Point(linegeo, (housenum::float-orginalstartnumber::float)/originalnumberrange::float));
841 newpoints := newpoints + 1;
842 --RAISE WARNING 'interpolation number % % ',prevnode.place_id,housenum;
845 havefirstpoint := false;
849 IF NOT havefirstpoint THEN
850 startnumber := ('0'||substring(nextnode.housenumber,'[0-9]+'))::integer;
851 IF startnumber IS NOT NULL AND startnumber > 0 THEN
852 havefirstpoint := true;
853 linestr := 'LINESTRING('||ST_X(nextnode.geometry)||' '||ST_Y(nextnode.geometry);
854 prevnode := nextnode;
856 --RAISE WARNING 'interpolation start % % ',nextnode.place_id,startnumber;
862 --RAISE WARNING 'interpolation points % ',newpoints;
869 CREATE OR REPLACE FUNCTION placex_insert() RETURNS TRIGGER
875 country_code VARCHAR(2);
876 default_language VARCHAR(10);
880 -- RAISE WARNING '%',NEW.osm_id;
883 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
884 -- RAISE WARNING 'bad highway %',NEW.osm_id;
887 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
888 -- RAISE WARNING 'empty landuse %',NEW.osm_id;
892 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
893 -- block all invalid geometary - just not worth the risk. seg faults are causing serious problems.
894 -- RAISE WARNING 'invalid geometry %',NEW.osm_id;
898 IF NEW.osm_type = 'R' THEN
899 -- invalid multipolygons can crash postgis, don't even bother to try!
902 NEW.geometry := ST_buffer(NEW.geometry,0);
903 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
904 -- RAISE WARNING 'Invalid geometary, rejecting: % %', NEW.osm_type, NEW.osm_id;
909 NEW.place_id := nextval('seq_place');
910 NEW.indexed_status := 1; --STATUS_NEW
912 IF NEW.rank_search >= 4 THEN
913 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
915 NEW.country_code := NULL;
918 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
919 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
921 -- copy 'name' to or from the default language (if there is a default language)
922 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
923 default_language := get_country_language_code(NEW.country_code);
924 IF default_language IS NOT NULL THEN
925 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
926 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
927 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
928 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
933 IF NEW.admin_level > 15 THEN
934 NEW.admin_level := 15;
937 IF NEW.housenumber IS NOT NULL THEN
938 i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
941 IF NEW.osm_type = 'X' THEN
942 -- E'X'ternal records should already be in the right format so do nothing
944 NEW.rank_search := 30;
945 NEW.rank_address := NEW.rank_search;
947 -- By doing in postgres we have the country available to us - currently only used for postcode
948 IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
950 IF NEW.postcode IS NULL THEN
951 -- most likely just a part of a multipolygon postcode boundary, throw it away
955 NEW.name := 'ref'=>NEW.postcode;
957 IF NEW.country_code = 'gb' THEN
959 IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
960 NEW.rank_search := 25;
961 NEW.rank_address := 5;
962 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
963 NEW.rank_search := 23;
964 NEW.rank_address := 5;
965 ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
966 NEW.rank_search := 21;
967 NEW.rank_address := 5;
970 ELSEIF NEW.country_code = 'de' THEN
972 IF NEW.postcode ~ '^([0-9]{5})$' THEN
973 NEW.rank_search := 21;
974 NEW.rank_address := 11;
978 -- Guess at the postcode format and coverage (!)
979 IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
980 NEW.rank_search := 21;
981 NEW.rank_address := 11;
983 -- Does it look splitable into and area and local code?
984 postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
986 IF postcode IS NOT NULL THEN
987 NEW.rank_search := 25;
988 NEW.rank_address := 11;
989 ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
990 NEW.rank_search := 21;
991 NEW.rank_address := 11;
996 ELSEIF NEW.class = 'place' THEN
997 IF NEW.type in ('continent') THEN
998 NEW.rank_search := 2;
999 NEW.rank_address := NEW.rank_search;
1000 ELSEIF NEW.type in ('sea') THEN
1001 NEW.rank_search := 2;
1002 NEW.rank_address := 0;
1003 ELSEIF NEW.type in ('country') THEN
1004 NEW.rank_search := 4;
1005 NEW.rank_address := NEW.rank_search;
1006 ELSEIF NEW.type in ('state') THEN
1007 NEW.rank_search := 8;
1008 NEW.rank_address := NEW.rank_search;
1009 ELSEIF NEW.type in ('region') THEN
1010 NEW.rank_search := 18; -- dropped from previous value of 10
1011 NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
1012 ELSEIF NEW.type in ('county') THEN
1013 NEW.rank_search := 12;
1014 NEW.rank_address := NEW.rank_search;
1015 ELSEIF NEW.type in ('city') THEN
1016 NEW.rank_search := 16;
1017 NEW.rank_address := NEW.rank_search;
1018 ELSEIF NEW.type in ('island') THEN
1019 NEW.rank_search := 17;
1020 NEW.rank_address := 0;
1021 ELSEIF NEW.type in ('town') THEN
1022 NEW.rank_search := 18;
1023 NEW.rank_address := 16;
1024 ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
1025 NEW.rank_search := 19;
1026 NEW.rank_address := 16;
1027 ELSEIF NEW.type in ('airport') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1028 NEW.rank_search := 18;
1029 NEW.rank_address := 17;
1030 ELSEIF NEW.type in ('moor') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1031 NEW.rank_search := 17;
1032 NEW.rank_address := 18;
1033 ELSEIF NEW.type in ('moor') THEN
1034 NEW.rank_search := 17;
1035 NEW.rank_address := 0;
1036 ELSEIF NEW.type in ('national_park') THEN
1037 NEW.rank_search := 18;
1038 NEW.rank_address := 18;
1039 ELSEIF NEW.type in ('suburb','croft','subdivision') THEN
1040 NEW.rank_search := 20;
1041 NEW.rank_address := NEW.rank_search;
1042 ELSEIF NEW.type in ('farm','locality','islet','isolated_dwelling','mountain_pass') THEN
1043 NEW.rank_search := 20;
1044 NEW.rank_address := 0;
1045 -- Irish townlands, tagged as place=locality and locality=townland
1046 IF (NEW.extratags -> 'locality') = 'townland' THEN
1047 NEW.rank_address := 20;
1049 ELSEIF NEW.type in ('hall_of_residence','neighbourhood','housing_estate','nature_reserve') THEN
1050 NEW.rank_search := 22;
1051 NEW.rank_address := 22;
1052 ELSEIF NEW.type in ('airport','street') THEN
1053 NEW.rank_search := 26;
1054 NEW.rank_address := NEW.rank_search;
1055 ELSEIF NEW.type in ('house','building') THEN
1056 NEW.rank_search := 30;
1057 NEW.rank_address := NEW.rank_search;
1058 ELSEIF NEW.type in ('houses') THEN
1059 -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
1060 -- insert new point into place for each derived building
1061 --i := create_interpolation(NEW.osm_id, NEW.housenumber);
1062 NEW.rank_search := 28;
1063 NEW.rank_address := 0;
1066 ELSEIF NEW.class = 'boundary' THEN
1067 IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
1068 -- RAISE WARNING 'invalid boundary %',NEW.osm_id;
1071 NEW.rank_search := NEW.admin_level * 2;
1072 NEW.rank_address := NEW.rank_search;
1073 ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
1074 NEW.rank_search := 22;
1075 NEW.rank_address := NEW.rank_search;
1076 -- any feature more than 5 square miles is probably worth indexing
1077 ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
1078 NEW.rank_search := 22;
1079 NEW.rank_address := NEW.rank_search;
1080 ELSEIF NEW.class = 'highway' AND NEW.name is NULL AND
1081 NEW.type in ('service','cycleway','path','footway','steps','bridleway','track','byway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1082 -- RAISE WARNING 'unnamed minor feature %',NEW.osm_id;
1084 ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
1086 ELSEIF NEW.class = 'waterway' AND NEW.name is NULL THEN
1088 ELSEIF NEW.class = 'waterway' THEN
1089 NEW.rank_address := 17;
1090 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
1091 NEW.rank_search := 27;
1092 NEW.rank_address := NEW.rank_search;
1093 ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
1094 NEW.rank_search := 26;
1095 NEW.rank_address := NEW.rank_search;
1096 ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
1097 NEW.rank_search := 4;
1098 NEW.rank_address := NEW.rank_search;
1099 ELSEIF NEW.class = 'natural' and NEW.type in ('coastline') THEN
1101 ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano') THEN
1102 NEW.rank_search := 18;
1103 NEW.rank_address := 0;
1108 IF NEW.rank_search > 30 THEN
1109 NEW.rank_search := 30;
1112 IF NEW.rank_address > 30 THEN
1113 NEW.rank_address := 30;
1116 IF (NEW.extratags -> 'capital') = 'yes' THEN
1117 NEW.rank_search := NEW.rank_search -1;
1120 -- Block import below rank 22
1121 -- IF NEW.rank_search > 22 THEN
1125 RETURN NEW; -- The following is not needed until doing diff updates, and slows the main index process down
1127 IF (ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(NEW.geometry)) THEN
1128 -- Performance: We just can't handle re-indexing for country level changes
1129 IF st_area(NEW.geometry) < 1 THEN
1130 -- mark items within the geometry for re-indexing
1131 -- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1133 -- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
1134 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1135 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);
1136 update placex set indexed_status = 2 where (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1137 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);
1140 -- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
1142 -- 16 = city, anything higher than city is effectively ignored (polygon required!)
1143 IF NEW.type='postcode' THEN
1145 ELSEIF NEW.rank_search < 16 THEN
1147 ELSEIF NEW.rank_search < 18 THEN
1149 ELSEIF NEW.rank_search < 20 THEN
1151 ELSEIF NEW.rank_search = 21 THEN
1153 ELSEIF NEW.rank_search < 24 THEN
1155 ELSEIF NEW.rank_search < 26 THEN
1156 diameter := 0.002; -- 100 to 200 meters
1157 ELSEIF NEW.rank_search < 28 THEN
1158 diameter := 0.001; -- 50 to 100 meters
1160 IF diameter > 0 THEN
1161 -- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
1162 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);
1167 -- add to tables for special search
1168 -- Note: won't work on initial import because the classtype tables
1169 -- do not yet exist. It won't hurt either.
1170 classtable := 'place_classtype_' || NEW.class || '_' || NEW.type;
1171 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO result;
1173 EXECUTE 'INSERT INTO ' || classtable::regclass || ' (place_id, centroid) VALUES ($1,$2)'
1174 USING NEW.place_id, ST_Centroid(NEW.geometry);
1178 -- IF NEW.rank_search < 26 THEN
1179 -- RAISE WARNING 'placex insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1188 CREATE OR REPLACE FUNCTION placex_update() RETURNS
1193 place_centroid GEOMETRY;
1195 search_maxdistance FLOAT[];
1196 search_mindistance FLOAT[];
1197 address_havelevel BOOLEAN[];
1198 -- search_scores wordscore[];
1199 -- search_scores_pos INTEGER;
1206 relation_members TEXT[];
1208 linkedplacex RECORD;
1209 search_diameter FLOAT;
1210 search_prevdiameter FLOAT;
1211 search_maxrank INTEGER;
1212 address_maxrank INTEGER;
1213 address_street_word_id INTEGER;
1214 parent_place_id_rank BIGINT;
1219 location_rank_search INTEGER;
1220 location_distance FLOAT;
1224 default_language TEXT;
1225 name_vector INTEGER[];
1226 nameaddress_vector INTEGER[];
1231 --RAISE WARNING '%',NEW.place_id;
1232 --RAISE WARNING '%', NEW;
1234 IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
1235 -- Silently do nothing
1240 IF OLD.indexed_status = 100 THEN
1241 delete from placex where place_id = OLD.place_id;
1245 IF NEW.indexed_status = 0 and OLD.indexed_status != 0 THEN
1247 NEW.indexed_date = now();
1249 IF NEW.class = 'place' AND NEW.type = 'houses' THEN
1250 i := create_interpolation(NEW.osm_id, NEW.housenumber);
1254 IF OLD.indexed_status > 1 THEN
1255 result := deleteSearchName(NEW.partition, NEW.place_id);
1256 DELETE FROM place_addressline WHERE place_id = NEW.place_id;
1257 DELETE FROM place_boundingbox where place_id = NEW.place_id;
1258 result := deleteRoad(NEW.partition, NEW.place_id);
1259 result := deleteLocationArea(NEW.partition, NEW.place_id);
1260 UPDATE placex set linked_place_id = null where linked_place_id = NEW.place_id;
1263 -- reclaculate country and partition (should probably have a country_code and calculated_country_code as seperate fields)
1264 IF NEW.rank_search >= 4 THEN
1265 SELECT country_code from place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type INTO NEW.country_code;
1266 NEW.country_code := lower(get_country_code(NEW.geometry, NEW.country_code));
1268 NEW.country_code := NULL;
1270 NEW.partition := get_partition(NEW.geometry, NEW.country_code);
1271 NEW.geometry_sector := geometry_sector(NEW.partition, NEW.geometry);
1273 -- Adding ourselves to the list simplifies address calculations later
1274 INSERT INTO place_addressline VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
1276 -- What level are we searching from
1277 search_maxrank := NEW.rank_search;
1279 -- Speed up searches - just use the centroid of the feature
1280 -- cheaper but less acurate
1281 place_centroid := ST_Centroid(NEW.geometry);
1282 NEW.centroid := null;
1284 -- Thought this wasn't needed but when we add new languages to the country_name table
1285 -- we need to update the existing names
1286 IF NEW.name is not null AND array_upper(akeys(NEW.name),1) > 1 THEN
1287 default_language := get_country_language_code(NEW.country_code);
1288 IF default_language IS NOT NULL THEN
1289 IF NEW.name ? 'name' AND NOT NEW.name ? ('name:'||default_language) THEN
1290 NEW.name := NEW.name || (('name:'||default_language) => (NEW.name -> 'name'));
1291 ELSEIF NEW.name ? ('name:'||default_language) AND NOT NEW.name ? 'name' THEN
1292 NEW.name := NEW.name || ('name' => (NEW.name -> ('name:'||default_language)));
1297 -- Initialise the name vector using our name
1298 name_vector := make_keywords(NEW.name);
1299 nameaddress_vector := '{}'::int[];
1301 -- some tag combinations add a special id for search
1302 tagpairid := get_tagpair(NEW.class,NEW.type);
1303 IF tagpairid IS NOT NULL THEN
1304 name_vector := name_vector + tagpairid;
1308 address_havelevel[i] := false;
1311 --RAISE WARNING '% %', NEW.place_id, NEW.rank_search;
1313 -- For low level elements we inherit from our parent road
1314 IF (NEW.rank_search > 27 OR (NEW.type = 'postcode' AND NEW.rank_search = 25)) THEN
1316 --RAISE WARNING 'finding street for %', NEW;
1318 NEW.parent_place_id := null;
1320 -- to do that we have to find our parent road
1321 -- Copy data from linked items (points on ways, addr:street links, relations)
1322 -- Note that addr:street links can only be indexed once the street itself is indexed
1323 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
1325 -- Is this node part of a relation?
1326 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['n'||NEW.osm_id]
1328 -- At the moment we only process one type of relation - associatedStreet
1329 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1330 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1331 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1332 --RAISE WARNING 'node in relation %',relation;
1333 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1334 and rank_search = 26 INTO NEW.parent_place_id;
1340 --RAISE WARNING 'x1';
1341 -- Is this node part of a way?
1342 FOR way IN select id from planet_osm_ways where nodes @> ARRAY[NEW.osm_id::integer] LOOP
1343 --RAISE WARNING '%', way;
1344 FOR location IN select * from placex where osm_type = 'W' and osm_id = way.id
1346 --RAISE WARNING '%', location;
1347 -- Way IS a road then we are on it - that must be our road
1348 IF location.rank_search = 26 AND NEW.parent_place_id IS NULL THEN
1349 --RAISE WARNING 'node in way that is a street %',location;
1350 NEW.parent_place_id := location.place_id;
1353 -- Is the WAY part of a relation
1354 IF NEW.parent_place_id IS NULL THEN
1355 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[location.osm_id::integer] and members @> ARRAY['w'||location.osm_id]
1357 -- At the moment we only process one type of relation - associatedStreet
1358 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL THEN
1359 FOR i IN 1..array_upper(relation.members, 1) BY 2 LOOP
1360 IF NEW.parent_place_id IS NULL AND relation.members[i+1] = 'street' THEN
1361 --RAISE WARNING 'node in way that is in a relation %',relation;
1362 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1363 and rank_search = 26 INTO NEW.parent_place_id;
1370 -- If the way contains an explicit name of a street copy it
1371 IF NEW.street IS NULL AND location.street IS NOT NULL THEN
1372 --RAISE WARNING 'node in way that has a streetname %',location;
1373 NEW.street := location.street;
1376 -- If this way is a street interpolation line then it is probably as good as we are going to get
1377 IF NEW.parent_place_id IS NULL AND NEW.street IS NULL AND location.class = 'place' and location.type='houses' THEN
1378 -- Try and find a way that is close roughly parellel to this line
1379 FOR relation IN SELECT place_id FROM placex
1380 WHERE ST_DWithin(location.geometry, placex.geometry, 0.001) and placex.rank_search = 26
1381 and st_geometrytype(location.geometry) in ('ST_LineString')
1382 ORDER BY (ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0))+
1383 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,0.5))+
1384 ST_distance(placex.geometry, ST_Line_Interpolate_Point(location.geometry,1))) ASC limit 1
1386 --RAISE WARNING 'using nearest street to address interpolation line,0.001 %',relation;
1387 NEW.parent_place_id := relation.place_id;
1396 --RAISE WARNING 'x2';
1398 IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'W' THEN
1399 -- Is this way part of a relation?
1400 FOR relation IN select * from planet_osm_rels where parts @> ARRAY[NEW.osm_id::integer] and members @> ARRAY['w'||NEW.osm_id]
1402 -- At the moment we only process one type of relation - associatedStreet
1403 IF relation.tags @> ARRAY['associatedStreet'] AND array_upper(relation.members, 1) IS NOT NULL 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 'way that is in a relation %',relation;
1407 SELECT place_id from placex where osm_type='W' and osm_id = substring(relation.members[i],2,200)::integer
1408 and rank_search = 26 INTO NEW.parent_place_id;
1415 --RAISE WARNING 'x3 %',NEW.parent_place_id;
1417 IF NEW.parent_place_id IS NULL AND NEW.street IS NOT NULL THEN
1418 address_street_word_id := get_name_id(make_standard_name(NEW.street));
1419 IF address_street_word_id IS NOT NULL THEN
1420 FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_id) LOOP
1421 NEW.parent_place_id := location.place_id;
1426 --RAISE WARNING 'x4 %',NEW.parent_place_id;
1427 -- Still nothing, just use the nearest road
1428 IF NEW.parent_place_id IS NULL THEN
1429 FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
1430 NEW.parent_place_id := location.place_id;
1435 --RAISE WARNING 'x6 %',NEW.parent_place_id;
1437 -- If we didn't find any road fallback to standard method
1438 IF NEW.parent_place_id IS NOT NULL THEN
1440 -- Add the street to the address as zero distance to force to front of list
1441 -- INSERT INTO place_addressline VALUES (NEW.place_id, NEW.parent_place_id, true, true, 0, 26);
1442 address_havelevel[26] := true;
1444 -- Import address details from parent, reclculating distance in process
1445 -- INSERT INTO place_addressline select NEW.place_id, x.address_place_id, x.fromarea, x.isaddress, ST_distance(NEW.geometry, placex.geometry), placex.rank_address
1446 -- from place_addressline as x join placex on (address_place_id = placex.place_id)
1447 -- where x.place_id = NEW.parent_place_id and x.address_place_id != NEW.parent_place_id;
1449 -- Get the details of the parent road
1450 select * from search_name where place_id = NEW.parent_place_id INTO location;
1451 NEW.country_code := location.country_code;
1453 --RAISE WARNING '%', NEW.name;
1454 -- If there is no name it isn't searchable, don't bother to create a search record
1455 IF NEW.name is NULL THEN
1459 -- Merge address from parent
1460 nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
1462 -- Performance, it would be more acurate to do all the rest of the import process but it takes too long
1463 -- Just be happy with inheriting from parent road only
1465 IF NEW.rank_search <= 25 THEN
1466 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1469 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1476 -- RAISE WARNING ' INDEXING: %',NEW;
1478 IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
1480 -- see if we have any special relation members
1481 select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
1483 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
1485 select * from placex where osm_type = upper(substring(relMember.member,1,1))
1486 and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex;
1488 -- If we don't already have one use this as the centre point of the geometry
1489 IF NEW.centroid IS NULL THEN
1490 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1493 -- merge in the label name, re-init word vector
1494 NEW.name := linkedPlacex.name || NEW.name;
1495 name_vector := make_keywords(NEW.name);
1497 -- merge in extra tags
1498 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1500 -- mark the linked place (excludes from search results)
1501 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1505 IF NEW.centroid IS NULL THEN
1507 FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
1509 select * from placex where osm_type = upper(substring(relMember.member,1,1))
1510 and osm_id = substring(relMember.member,2,10000)::integer order by rank_search desc limit 1 into linkedPlacex;
1512 -- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
1513 -- But that can be fixed by explicitly setting the label in the data
1514 IF make_standard_name(NEW.name->'name') = make_standard_name(linkedPlacex.name->'name')
1515 AND NEW.rank_search = linkedPlacex.rank_search THEN
1517 -- If we don't already have one use this as the centre point of the geometry
1518 IF NEW.centroid IS NULL THEN
1519 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1522 -- merge in the name, re-init word vector
1523 NEW.name := linkedPlacex.name || NEW.name;
1524 name_vector := make_keywords(NEW.name);
1526 -- merge in extra tags
1527 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1529 -- mark the linked place (excludes from search results)
1530 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1537 -- not found one yet? how about doing a name search
1538 IF NEW.centroid IS NULL AND NEW.name->'name' is not null and make_standard_name(NEW.name->'name') != '' THEN
1540 FOR linkedPlacex IN select placex.* from placex WHERE
1541 make_standard_name(name->'name') = make_standard_name(NEW.name->'name')
1542 AND placex.rank_search = NEW.rank_search
1543 AND placex.place_id != NEW.place_id
1545 AND st_contains(NEW.geometry, placex.geometry)
1548 -- If we don't already have one use this as the centre point of the geometry
1549 IF NEW.centroid IS NULL THEN
1550 NEW.centroid := coalesce(linkedPlacex.centroid,st_centroid(linkedPlacex.geometry));
1553 -- merge in the name, re-init word vector
1554 NEW.name := linkedPlacex.name || NEW.name;
1555 name_vector := make_keywords(NEW.name);
1557 -- merge in extra tags
1558 NEW.extratags := linkedPlacex.extratags || NEW.extratags;
1560 -- mark the linked place (excludes from search results)
1561 UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
1566 IF NEW.centroid IS NOT NULL THEN
1567 place_centroid := NEW.centroid;
1572 NEW.parent_place_id = 0;
1573 parent_place_id_rank = 0;
1575 -- convert isin to array of tokenids
1576 isin_tokens := '{}'::int[];
1577 IF NEW.isin IS NOT NULL THEN
1578 isin := regexp_split_to_array(NEW.isin, E'[;,]');
1579 IF array_upper(isin, 1) IS NOT NULL THEN
1580 FOR i IN 1..array_upper(isin, 1) LOOP
1581 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1582 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1583 isin_tokens := isin_tokens || address_street_word_id;
1588 IF NEW.postcode IS NOT NULL THEN
1589 isin := regexp_split_to_array(NEW.postcode, E'[;,]');
1590 IF array_upper(isin, 1) IS NOT NULL THEN
1591 FOR i IN 1..array_upper(isin, 1) LOOP
1592 address_street_word_id := get_name_id(make_standard_name(isin[i]));
1593 IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
1594 isin_tokens := isin_tokens || address_street_word_id;
1599 --RAISE WARNING 'ISIN: %', isin_tokens;
1601 -- Process area matches
1602 location_rank_search := 100;
1603 location_distance := 0;
1604 --RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
1605 FOR location IN SELECT * from getNearFeatures(NEW.partition, place_centroid, search_maxrank, isin_tokens) LOOP
1607 --RAISE WARNING ' AREA: %',location;
1609 IF location.rank_search < location_rank_search THEN
1610 location_rank_search := location.rank_search;
1611 location_distance := location.distance * 1.5;
1614 IF location.distance < location_distance OR NOT location.isguess THEN
1616 -- Add it to the list of search terms
1617 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1618 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1619 address_havelevel[location.rank_address] := true;
1621 --RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
1623 IF location.rank_address > parent_place_id_rank THEN
1624 NEW.parent_place_id = location.place_id;
1625 parent_place_id_rank = location.rank_address;
1632 -- try using the isin value to find parent places
1633 IF array_upper(isin_tokens, 1) IS NOT NULL THEN
1634 FOR i IN 1..array_upper(isin_tokens, 1) LOOP
1635 --RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
1637 FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
1639 --RAISE WARNING ' ISIN: %',location;
1641 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1642 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
1643 address_havelevel[location.rank_address] := true;
1645 IF location.rank_address > parent_place_id_rank THEN
1646 NEW.parent_place_id = location.place_id;
1647 parent_place_id_rank = location.rank_address;
1655 -- for long ways we should add search terms for the entire length
1656 IF st_length(NEW.geometry) > 0.05 THEN
1658 location_rank_search := 100;
1659 location_distance := 0;
1661 FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
1663 IF location.rank_search < location_rank_search THEN
1664 location_rank_search := location.rank_search;
1665 location_distance := location.distance * 1.5;
1668 IF location.distance < location_distance THEN
1670 -- Add it to the list of search terms
1671 nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
1672 INSERT INTO place_addressline VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
1680 -- if we have a name add this to the name search table
1681 IF NEW.name IS NOT NULL THEN
1683 IF NEW.rank_search <= 25 THEN
1684 result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
1687 IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
1688 result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
1691 result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid);
1693 -- INSERT INTO search_name values (NEW.place_id, NEW.rank_search, NEW.rank_search, 0, NEW.country_code, name_vector, nameaddress_vector, place_centroid);
1696 -- If we've not managed to pick up a better one - default centroid
1697 IF NEW.centroid IS NULL THEN
1698 NEW.centroid := place_centroid;
1708 CREATE OR REPLACE FUNCTION placex_delete() RETURNS TRIGGER
1715 update placex set linked_place_id = null where linked_place_id = OLD.place_id;
1716 update placex set indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
1718 IF OLD.rank_address < 30 THEN
1720 -- mark everything linked to this place for re-indexing
1721 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD.place_id
1722 and placex.place_id = place_addressline.place_id and indexed_status = 0;
1724 DELETE FROM place_addressline where address_place_id = OLD.place_id;
1726 b := deleteRoad(OLD.partition, OLD.place_id);
1728 update placex set indexed_status = 2 where parent_place_id = OLD.place_id and indexed_status = 0;
1732 IF OLD.rank_address < 26 THEN
1733 b := deleteLocationArea(OLD.partition, OLD.place_id);
1736 IF OLD.name is not null THEN
1737 b := deleteSearchName(OLD.partition, OLD.place_id);
1740 DELETE FROM place_addressline where place_id = OLD.place_id;
1742 -- remove from tables for special search
1743 classtable := 'place_classtype_' || OLD.class || '_' || OLD.type;
1744 SELECT count(*)>0 FROM pg_tables WHERE tablename = classtable INTO b;
1746 EXECUTE 'DELETE FROM ' || classtable::regclass || ' WHERE place_id = $1' USING OLD.place_id;
1755 CREATE OR REPLACE FUNCTION place_delete() RETURNS TRIGGER
1761 -- RAISE WARNING 'delete: % % % %',OLD.osm_type,OLD.osm_id,OLD.class,OLD.type;
1763 -- deleting large polygons can have a massive effect ont he system - require manual intervention to let them through
1764 IF st_area(OLD.geometry) > 2 THEN
1765 insert into import_polygon_delete values (OLD.osm_type,OLD.osm_id,OLD.class,OLD.type);
1770 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;
1772 -- delete from placex where osm_type = OLD.osm_type and osm_id = OLD.osm_id and class = OLD.class and type = OLD.type;
1779 CREATE OR REPLACE FUNCTION place_insert() RETURNS TRIGGER
1784 existingplacex RECORD;
1785 existinggeometry GEOMETRY;
1786 existingplace_id BIGINT;
1791 IF FALSE and NEW.osm_type = 'R' THEN
1792 RAISE WARNING '-----------------------------------------------------------------------------------';
1793 RAISE WARNING 'place_insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,st_area(NEW.geometry);
1794 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;
1795 RAISE WARNING '%', existingplacex;
1798 -- Just block these - lots and pointless
1799 IF NEW.class = 'highway' and NEW.type in ('turning_circle','traffic_signals','mini_roundabout','noexit','crossing') THEN
1802 IF NEW.class in ('landuse','natural') and NEW.name is null THEN
1806 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
1807 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code,
1808 now(), ST_IsValidReason(NEW.geometry), null, NEW.geometry);
1809 -- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1813 -- Patch in additional country names
1814 IF NEW.admin_level = 2 AND NEW.type = 'administrative' AND NEW.country_code is not null THEN
1815 select country_name.name || NEW.name from country_name where country_name.country_code = lower(NEW.country_code) INTO NEW.name;
1818 -- Have we already done this place?
1819 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;
1821 -- Get the existing place_id
1822 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;
1824 -- Handle a place changing type by removing the old data
1825 -- My generated 'place' types are causing havok because they overlap with real keys
1826 -- TODO: move them to their own special purpose key/class to avoid collisions
1827 IF existing.osm_type IS NULL AND (NEW.type not in ('postcode','house','houses')) THEN
1828 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type not in ('postcode','house','houses');
1831 -- RAISE WARNING 'Existing: %',existing.place_id;
1834 IF existing.geometry is not null AND st_isvalid(existing.geometry)
1835 AND st_area(existing.geometry) > 0.02
1836 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1837 AND st_area(NEW.geometry) < st_area(existing.geometry)*0.5
1839 INSERT INTO import_polygon_error values (NEW.osm_type, NEW.osm_id, NEW.class, NEW.type, NEW.name, NEW.country_code, now(),
1840 'Area reduced from '||st_area(existing.geometry)||' to '||st_area(NEW.geometry), existing.geometry, NEW.geometry);
1844 DELETE from import_polygon_error where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1845 DELETE from import_polygon_delete where osm_type = NEW.osm_type and osm_id = NEW.osm_id;
1847 -- To paraphrase, if there isn't an existing item, OR if the admin level has changed, OR if it is a major change in geometry
1848 IF existing.osm_type IS NULL
1849 OR existingplacex.osm_type IS NULL
1850 OR coalesce(existing.admin_level, 100) != coalesce(NEW.admin_level, 100)
1851 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1852 OR (existing.geometry::text != NEW.geometry::text AND ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)) > 0.01 AND NOT
1853 (ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')))
1856 -- IF existing.osm_type IS NULL THEN
1857 -- RAISE WARNING 'no existing place';
1859 -- IF existingplacex.osm_type IS NULL THEN
1860 -- RAISE WARNING 'no existing placex %', existingplacex;
1863 -- RAISE WARNING 'delete and replace';
1865 IF existing.osm_type IS NOT NULL THEN
1866 -- RAISE WARNING 'insert delete % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,ST_Distance(ST_Centroid(existing.geometry),ST_Centroid(NEW.geometry)),existing;
1867 DELETE FROM place where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
1870 -- RAISE WARNING 'delete and replace2';
1872 -- No - process it as a new insertion (hopefully of low rank or it will be slow)
1873 insert into placex (osm_type, osm_id, class, type, name, admin_level, housenumber,
1874 street, isin, postcode, country_code, extratags, geometry)
1875 values (NEW.osm_type
1890 -- RAISE WARNING 'insert done % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
1895 -- Various ways to do the update
1897 -- Debug, what's changed?
1899 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '') THEN
1900 RAISE WARNING 'update details, name: % % % %',NEW.osm_type,NEW.osm_id,existing.name::text,NEW.name::text;
1902 IF coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '') THEN
1903 RAISE WARNING 'update details, housenumber: % % % %',NEW.osm_type,NEW.osm_id,existing.housenumber,NEW.housenumber;
1905 IF coalesce(existing.street, '') != coalesce(NEW.street, '') THEN
1906 RAISE WARNING 'update details, street: % % % %',NEW.osm_type,NEW.osm_id,existing.street,NEW.street;
1908 IF coalesce(existing.isin, '') != coalesce(NEW.isin, '') THEN
1909 RAISE WARNING 'update details, isin: % % % %',NEW.osm_type,NEW.osm_id,existing.isin,NEW.isin;
1911 IF coalesce(existing.postcode, '') != coalesce(NEW.postcode, '') THEN
1912 RAISE WARNING 'update details, postcode: % % % %',NEW.osm_type,NEW.osm_id,existing.postcode,NEW.postcode;
1914 IF coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1915 RAISE WARNING 'update details, country_code: % % % %',NEW.osm_type,NEW.osm_id,existing.country_code,NEW.country_code;
1919 -- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
1920 IF existing.geometry::text != NEW.geometry::text
1921 AND ST_GeometryType(existing.geometry) in ('ST_Polygon','ST_MultiPolygon')
1922 AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon')
1925 -- Get the version of the geometry actually used (in placex table)
1926 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;
1928 -- Performance limit
1929 IF st_area(NEW.geometry) < 0.000000001 AND st_area(existinggeometry) < 1 THEN
1931 -- 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
1932 update placex set indexed_status = 2 where indexed_status = 0 and
1933 (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1934 AND NOT (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1935 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1937 update placex set indexed_status = 2 where indexed_status = 0 and
1938 (ST_Contains(existinggeometry, placex.geometry) OR ST_Intersects(existinggeometry, placex.geometry))
1939 AND NOT (ST_Contains(NEW.geometry, placex.geometry) OR ST_Intersects(NEW.geometry, placex.geometry))
1940 AND rank_search > existingplacex.rank_search AND (rank_search < 28 or name is not null);
1946 -- Special case - if we are just adding extra words we hack them into the search_name table rather than reindexing
1947 IF FALSE AND existingplacex.rank_search < 26
1948 AND coalesce(existing.housenumber, '') = coalesce(NEW.housenumber, '')
1949 AND coalesce(existing.street, '') = coalesce(NEW.street, '')
1950 AND coalesce(existing.isin, '') = coalesce(NEW.isin, '')
1951 AND coalesce(existing.postcode, '') = coalesce(NEW.postcode, '')
1952 AND coalesce(existing.country_code, '') = coalesce(NEW.country_code, '')
1953 AND coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1956 IF NOT update_location_nameonly(existingplacex.place_id, NEW.name) THEN
1958 IF st_area(NEW.geometry) < 0.5 THEN
1959 UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1960 and placex.place_id = place_addressline.place_id and indexed_status = 0
1961 and (rank_search < 28 or name is not null);
1968 -- Anything else has changed - reindex the lot
1969 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1970 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1971 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1972 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1973 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1974 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '') THEN
1976 -- performance, can't take the load of re-indexing a whole country / huge area
1977 IF st_area(NEW.geometry) < 0.5 THEN
1978 -- UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = existingplacex.place_id
1979 -- and placex.place_id = place_addressline.place_id and indexed_status = 0;
1986 IF coalesce(existing.name::text, '') != coalesce(NEW.name::text, '')
1987 OR coalesce(existing.extratags::text, '') != coalesce(NEW.extratags::text, '')
1988 OR coalesce(existing.housenumber, '') != coalesce(NEW.housenumber, '')
1989 OR coalesce(existing.street, '') != coalesce(NEW.street, '')
1990 OR coalesce(existing.isin, '') != coalesce(NEW.isin, '')
1991 OR coalesce(existing.postcode, '') != coalesce(NEW.postcode, '')
1992 OR coalesce(existing.country_code, '') != coalesce(NEW.country_code, '')
1993 OR existing.geometry::text != NEW.geometry::text
1998 housenumber = NEW.housenumber,
1999 street = NEW.street,
2001 postcode = NEW.postcode,
2002 country_code = NEW.country_code,
2003 extratags = NEW.extratags,
2004 geometry = NEW.geometry
2005 where osm_type = NEW.osm_type and osm_id = NEW.osm_id and class = NEW.class and type = NEW.type;
2009 housenumber = NEW.housenumber,
2010 street = NEW.street,
2012 postcode = NEW.postcode,
2013 country_code = NEW.country_code,
2014 parent_place_id = null,
2015 extratags = NEW.extratags,
2017 geometry = NEW.geometry
2018 where place_id = existingplacex.place_id;
2020 -- now done as part of insert
2021 -- partition := get_partition(NEW.geometry, existingplacex.country_code);
2022 -- result := update_location(partition, existingplacex.place_id, existingplacex.country_code, NEW.name, existingplacex.rank_search, existingplacex.rank_address, NEW.geometry);
2026 -- Abort the add (we modified the existing place instead)
2030 $$ LANGUAGE plpgsql;
2032 CREATE OR REPLACE FUNCTION get_name_by_language(name hstore, languagepref TEXT[]) RETURNS TEXT
2039 IF name is null THEN
2043 search := languagepref;
2045 FOR j IN 1..array_upper(search, 1) LOOP
2046 IF name ? search[j] AND trim(name->search[j]) != '' THEN
2047 return trim(name->search[j]);
2054 LANGUAGE plpgsql IMMUTABLE;
2056 CREATE OR REPLACE FUNCTION get_connected_ways(way_ids INTEGER[]) RETURNS SETOF planet_osm_ways
2059 searchnodes INTEGER[];
2064 searchnodes := '{}';
2065 FOR j IN 1..array_upper(way_ids, 1) LOOP
2067 select nodes from planet_osm_ways where id = way_ids[j] LIMIT 1
2069 IF not (ARRAY[location.nodes] <@ searchnodes) THEN
2070 searchnodes := searchnodes || location.nodes;
2075 RETURN QUERY select * from planet_osm_ways where nodes && searchnodes and NOT ARRAY[id] <@ way_ids;
2078 LANGUAGE plpgsql IMMUTABLE;
2080 CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
2091 search := ARRAY['ref'];
2094 select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
2097 select rank_address,name,distance,length(name::text) as namelength
2098 from place_addressline join placex on (address_place_id = placex.place_id)
2099 where place_addressline.place_id = for_place_id and rank_address in (5,11)
2100 order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
2102 IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
2103 FOR j IN 1..array_upper(search, 1) LOOP
2104 FOR k IN 1..array_upper(location.name, 1) LOOP
2105 IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
2106 result[(100 - location.rank_address)] := trim(location.name[k].value);
2107 found := location.rank_address;
2114 RETURN array_to_string(result,', ');
2119 CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, languagepref TEXT[]) RETURNS TEXT
2131 FOR location IN select * from get_addressdata(for_place_id) where isaddress order by rank_address desc LOOP
2132 currresult := trim(get_name_by_language(location.name, languagepref));
2133 IF currresult != prevresult AND currresult IS NOT NULL THEN
2134 result[(100 - location.rank_address)] := trim(get_name_by_language(location.name, languagepref));
2135 prevresult := currresult;
2139 RETURN array_to_string(result,', ');
2144 DROP TYPE addressline CASCADE;
2145 create type addressline as (
2152 admin_level INTEGER,
2155 rank_address INTEGER,
2159 CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT) RETURNS setof addressline
2162 for_place_id BIGINT;
2167 countrylocation RECORD;
2168 searchcountrycode varchar(2);
2169 searchhousenumber TEXT;
2170 searchhousename HSTORE;
2171 searchrankaddress INTEGER;
2172 searchpostcode TEXT;
2179 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_tiger
2180 WHERE place_id = in_place_id
2181 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2183 IF for_place_id IS NULL THEN
2184 select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
2185 WHERE place_id = in_place_id
2186 INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2189 IF for_place_id IS NULL THEN
2190 select parent_place_id, country_code, housenumber, rank_address, postcode, name, class, type from placex
2191 WHERE place_id = in_place_id and rank_address = 30
2192 INTO for_place_id, searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
2195 IF for_place_id IS NULL THEN
2196 for_place_id := in_place_id;
2197 select country_code, housenumber, rank_address, postcode, null from placex where place_id = for_place_id
2198 INTO searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename;
2201 --RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
2204 hadcountry := false;
2206 select placex.place_id, osm_type, osm_id,
2207 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2208 class, type, admin_level, true as fromarea, true as isaddress,
2209 CASE WHEN rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2210 0 as distance, country_code
2212 where place_id = for_place_id
2214 --RAISE WARNING '%',location;
2215 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2216 searchcountrycode := location.country_code;
2218 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2219 location.isaddress := FALSE;
2221 IF location.rank_address = 4 AND location.isaddress THEN
2224 IF location.rank_address < 4 AND NOT hadcountry THEN
2225 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2226 IF countryname IS NOT NULL THEN
2227 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2228 RETURN NEXT countrylocation;
2231 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2232 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2233 location.distance)::addressline;
2234 RETURN NEXT countrylocation;
2235 found := location.rank_address;
2239 select placex.place_id, osm_type, osm_id,
2240 CASE WHEN class = 'place' and type = 'postcode' THEN 'name' => postcode ELSE name END as name,
2241 class, type, admin_level, fromarea, isaddress,
2242 CASE WHEN address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
2243 distance,country_code
2244 from place_addressline join placex on (address_place_id = placex.place_id)
2245 where place_addressline.place_id = for_place_id
2246 and (cached_rank_address > 0 AND cached_rank_address < searchrankaddress)
2247 and address_place_id != for_place_id
2248 and (placex.country_code IS NULL OR searchcountrycode IS NULL OR placex.country_code = searchcountrycode OR rank_address < 4)
2249 order by rank_address desc,isaddress desc,fromarea desc,distance asc,rank_search desc
2251 --RAISE WARNING '%',location;
2252 IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
2253 searchcountrycode := location.country_code;
2255 IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
2256 location.isaddress := FALSE;
2258 IF location.rank_address = 4 AND location.isaddress THEN
2261 IF location.rank_address < 4 AND NOT hadcountry THEN
2262 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2263 IF countryname IS NOT NULL THEN
2264 countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2265 RETURN NEXT countrylocation;
2268 countrylocation := ROW(location.place_id, location.osm_type, location.osm_id, location.name, location.class,
2269 location.type, location.admin_level, location.fromarea, location.isaddress, location.rank_address,
2270 location.distance)::addressline;
2271 RETURN NEXT countrylocation;
2272 found := location.rank_address;
2276 select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
2277 --RAISE WARNING '% % %',found,searchcountrycode,countryname;
2278 IF countryname IS NOT NULL THEN
2279 location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
2280 RETURN NEXT location;
2284 IF searchcountrycode IS NOT NULL THEN
2285 location := ROW(null, null, null, 'ref'=>searchcountrycode, 'place', 'country_code', null, true, false, 4, 0)::addressline;
2286 RETURN NEXT location;
2289 IF searchhousename IS NOT NULL THEN
2290 location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
2291 -- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
2292 RETURN NEXT location;
2295 IF searchhousenumber IS NOT NULL THEN
2296 location := ROW(in_place_id, null, null, 'ref'=>searchhousenumber, 'place', 'house_number', null, true, true, 28, 0)::addressline;
2297 RETURN NEXT location;
2300 IF searchpostcode IS NOT NULL THEN
2301 location := ROW(null, null, null, 'ref'=>searchpostcode, 'place', 'postcode', null, true, true, 5, 0)::addressline;
2302 RETURN NEXT location;
2310 CREATE OR REPLACE FUNCTION get_place_boundingbox(search_place_id BIGINT) RETURNS place_boundingbox
2313 result place_boundingbox;
2314 numfeatures integer;
2316 select * from place_boundingbox into result where place_id = search_place_id;
2317 IF result.place_id IS NULL THEN
2318 -- remove isaddress = true because if there is a matching polygon it always wins
2319 select count(*) from place_addressline where address_place_id = search_place_id into numfeatures;
2320 insert into place_boundingbox select place_id,
2321 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2322 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2323 numfeatures, ST_Area(geometry),
2324 geometry as area from location_area where place_id = search_place_id;
2325 select * from place_boundingbox into result where place_id = search_place_id;
2327 IF result.place_id IS NULL THEN
2329 insert into place_boundingbox select address_place_id,
2330 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2331 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2332 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2333 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2334 from (select * from place_addressline where address_place_id = search_place_id order by cached_rank_address limit 4000) as place_addressline join placex using (place_id)
2335 where address_place_id = search_place_id
2336 -- and (isaddress = true OR place_id = search_place_id)
2337 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2338 group by address_place_id limit 1;
2339 select * from place_boundingbox into result where place_id = search_place_id;
2346 -- don't do the operation if it would be slow
2347 CREATE OR REPLACE FUNCTION get_place_boundingbox_quick(search_place_id BIGINT) RETURNS place_boundingbox
2350 result place_boundingbox;
2351 numfeatures integer;
2354 select * from place_boundingbox into result where place_id = search_place_id;
2355 IF result IS NULL AND rank > 14 THEN
2356 select count(*) from place_addressline where address_place_id = search_place_id and isaddress = true into numfeatures;
2357 insert into place_boundingbox select place_id,
2358 ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),4)),ST_Y(ST_PointN(ExteriorRing(ST_Box2D(geometry)),2)),
2359 ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),1)),ST_X(ST_PointN(ExteriorRing(ST_Box2D(geometry)),3)),
2360 numfeatures, ST_Area(geometry),
2361 geometry as area from location_area where place_id = search_place_id;
2362 select * from place_boundingbox into result where place_id = search_place_id;
2364 IF result IS NULL THEN
2365 select rank_search from placex where place_id = search_place_id into rank;
2368 insert into place_boundingbox select address_place_id,
2369 min(ST_Y(ST_Centroid(geometry))) as minlon,max(ST_Y(ST_Centroid(geometry))) as maxlon,
2370 min(ST_X(ST_Centroid(geometry))) as minlat,max(ST_X(ST_Centroid(geometry))) as maxlat,
2371 count(*), ST_Area(ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001)) as area,
2372 ST_Buffer(ST_Convexhull(ST_Collect(geometry)),0.0001) as boundary
2373 from place_addressline join placex using (place_id)
2374 where address_place_id = search_place_id
2375 and (isaddress = true OR place_id = search_place_id)
2376 and (st_length(geometry) < 0.01 or place_id = search_place_id)
2377 group by address_place_id limit 1;
2378 select * from place_boundingbox into result where place_id = search_place_id;
2386 CREATE OR REPLACE FUNCTION update_place(search_place_id BIGINT) RETURNS BOOLEAN
2389 result place_boundingbox;
2390 numfeatures integer;
2394 housenumber = place.housenumber,
2395 street = place.street,
2397 postcode = place.postcode,
2398 country_code = place.country_code,
2399 parent_place_id = null
2401 where placex.place_id = search_place_id
2402 and place.osm_type = placex.osm_type and place.osm_id = placex.osm_id
2403 and place.class = placex.class and place.type = placex.type;
2404 update placex set indexed_status = 2 where place_id = search_place_id;
2405 update placex set indexed_status = 0 where place_id = search_place_id;
2411 CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
2417 ELSEIF rank < 4 THEN
2419 ELSEIF rank < 8 THEN
2421 ELSEIF rank < 12 THEN
2423 ELSEIF rank < 16 THEN
2425 ELSEIF rank = 16 THEN
2427 ELSEIF rank = 17 THEN
2428 RETURN 'Town / Island';
2429 ELSEIF rank = 18 THEN
2430 RETURN 'Village / Hamlet';
2431 ELSEIF rank = 20 THEN
2433 ELSEIF rank = 21 THEN
2434 RETURN 'Postcode Area';
2435 ELSEIF rank = 22 THEN
2436 RETURN 'Croft / Farm / Locality / Islet';
2437 ELSEIF rank = 23 THEN
2438 RETURN 'Postcode Area';
2439 ELSEIF rank = 25 THEN
2440 RETURN 'Postcode Point';
2441 ELSEIF rank = 26 THEN
2442 RETURN 'Street / Major Landmark';
2443 ELSEIF rank = 27 THEN
2444 RETURN 'Minory Street / Path';
2445 ELSEIF rank = 28 THEN
2446 RETURN 'House / Building';
2448 RETURN 'Other: '||rank;
2455 CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
2461 ELSEIF rank < 2 THEN
2463 ELSEIF rank < 4 THEN
2465 ELSEIF rank = 5 THEN
2467 ELSEIF rank < 8 THEN
2469 ELSEIF rank < 12 THEN
2471 ELSEIF rank < 16 THEN
2473 ELSEIF rank = 16 THEN
2475 ELSEIF rank = 17 THEN
2476 RETURN 'Town / Village / Hamlet';
2477 ELSEIF rank = 20 THEN
2479 ELSEIF rank = 21 THEN
2480 RETURN 'Postcode Area';
2481 ELSEIF rank = 22 THEN
2482 RETURN 'Croft / Farm / Locality / Islet';
2483 ELSEIF rank = 23 THEN
2484 RETURN 'Postcode Area';
2485 ELSEIF rank = 25 THEN
2486 RETURN 'Postcode Point';
2487 ELSEIF rank = 26 THEN
2488 RETURN 'Street / Major Landmark';
2489 ELSEIF rank = 27 THEN
2490 RETURN 'Minory Street / Path';
2491 ELSEIF rank = 28 THEN
2492 RETURN 'House / Building';
2494 RETURN 'Other: '||rank;
2501 CREATE OR REPLACE FUNCTION get_word_suggestion(srcword TEXT) RETURNS TEXT
2508 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2509 SELECT word FROM word WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 1 into result;
2516 CREATE OR REPLACE FUNCTION get_word_suggestions(srcword TEXT) RETURNS TEXT[]
2524 trigramtoken := regexp_replace(make_standard_name(srcword),E'([^0-9])\\1+',E'\\1','g');
2526 FOR r IN SELECT word,similarity(word_trigram, trigramtoken) as score FROM word
2527 WHERE word_trigram like ' %' and word_trigram % trigramtoken ORDER BY similarity(word_trigram, trigramtoken) DESC, word limit 4
2529 result[coalesce(array_upper(result,1)+1,1)] := r.word;
2537 CREATE OR REPLACE FUNCTION tigger_create_interpolation(linegeo GEOMETRY, in_startnumber INTEGER,
2538 in_endnumber INTEGER, interpolationtype TEXT,
2539 in_street TEXT, in_isin TEXT, in_postcode TEXT) RETURNS INTEGER
2543 startnumber INTEGER;
2548 numberrange INTEGER;
2549 rangestartnumber INTEGER;
2550 place_centroid GEOMETRY;
2551 out_partition INTEGER;
2552 out_parent_place_id BIGINT;
2554 address_street_word_id INTEGER;
2558 IF in_endnumber > in_startnumber THEN
2559 startnumber = in_startnumber;
2560 endnumber = in_endnumber;
2562 startnumber = in_endnumber;
2563 endnumber = in_startnumber;
2566 numberrange := endnumber - startnumber;
2567 rangestartnumber := startnumber;
2569 IF (interpolationtype = 'odd' AND startnumber%2 = 0) OR (interpolationtype = 'even' AND startnumber%2 = 1) THEN
2570 startnumber := startnumber + 1;
2573 IF (interpolationtype = 'odd' OR interpolationtype = 'even') THEN
2575 ELSE -- everything else assumed to be 'all'
2580 -- Filter out really broken tiger data
2581 IF numberrange > 0 AND (numberrange::float/stepsize::float > 500)
2582 AND ST_length(linegeo)/(numberrange::float/stepsize::float) < 0.000001 THEN
2583 RAISE WARNING 'Road too short for number range % to % on %, % (%)',startnumber,endnumber,in_street,in_isin,
2584 ST_length(linegeo)/(numberrange::float/stepsize::float);
2588 place_centroid := ST_Centroid(linegeo);
2589 out_partition := get_partition(place_centroid, 'us');
2590 out_parent_place_id := null;
2592 address_street_word_id := get_name_id(make_standard_name(in_street));
2593 IF address_street_word_id IS NOT NULL THEN
2594 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2595 out_parent_place_id := location.place_id;
2599 IF out_parent_place_id IS NULL THEN
2600 FOR location IN SELECT place_id FROM getNearestParellelRoadFeature(out_partition, linegeo) LOOP
2601 out_parent_place_id := location.place_id;
2605 IF out_parent_place_id IS NULL THEN
2606 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2607 out_parent_place_id := location.place_id;
2612 FOR housenum IN startnumber..endnumber BY stepsize LOOP
2613 insert into location_property_tiger (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2614 values (nextval('seq_place'), out_partition, out_parent_place_id, housenum, in_postcode,
2615 ST_Line_Interpolate_Point(linegeo, (housenum::float-rangestartnumber::float)/numberrange::float));
2616 newpoints := newpoints + 1;
2624 CREATE OR REPLACE FUNCTION aux_create_property(pointgeo GEOMETRY, in_housenumber TEXT,
2625 in_street TEXT, in_isin TEXT, in_postcode TEXT, in_countrycode char(2)) RETURNS INTEGER
2630 place_centroid GEOMETRY;
2631 out_partition INTEGER;
2632 out_parent_place_id BIGINT;
2634 address_street_word_id INTEGER;
2639 place_centroid := ST_Centroid(pointgeo);
2640 out_partition := get_partition(place_centroid, in_countrycode);
2641 out_parent_place_id := null;
2643 address_street_word_id := get_name_id(make_standard_name(in_street));
2644 IF address_street_word_id IS NOT NULL THEN
2645 FOR location IN SELECT * from getNearestNamedRoadFeature(out_partition, place_centroid, address_street_word_id) LOOP
2646 out_parent_place_id := location.place_id;
2650 IF out_parent_place_id IS NULL THEN
2651 FOR location IN SELECT place_id FROM getNearestRoadFeature(out_partition, place_centroid) LOOP
2652 out_parent_place_id := location.place_id;
2656 out_postcode := in_postcode;
2657 IF out_postcode IS NULL THEN
2658 SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
2660 IF out_postcode IS NULL THEN
2661 out_postcode := getNearestPostcode(out_partition, place_centroid);
2665 insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
2666 values (nextval('seq_place'), out_partition, out_parent_place_id, in_housenumber, out_postcode, place_centroid);
2667 newpoints := newpoints + 1;
2674 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], member TEXT) RETURNS TEXT[]
2681 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2682 IF members[i+1] = member THEN
2683 result := result || members[i];
2692 CREATE OR REPLACE FUNCTION get_osm_rel_members(members TEXT[], memberLabels TEXT[]) RETURNS SETOF TEXT
2698 FOR i IN 1..ARRAY_UPPER(members,1) BY 2 LOOP
2699 IF members[i+1] = ANY(memberLabels) THEN
2700 RETURN NEXT members[i];