2016-03-30 23:48:18 +03:00
-- Splits the line at the given point and returns the two parts
-- in a multilinestring.
CREATE OR REPLACE FUNCTION split_line_on_node ( line GEOMETRY , point GEOMETRY )
RETURNS GEOMETRY
AS $ $
BEGIN
RETURN ST_Split ( ST_Snap ( line , point , 0 . 0005 ) , point ) ;
END ;
$ $
LANGUAGE plpgsql ;
2010-11-09 13:19:36 +03:00
CREATE OR REPLACE FUNCTION geometry_sector ( partition INTEGER , place geometry ) RETURNS INTEGER
2010-10-24 03:12:37 +04:00
AS $ $
DECLARE
NEWgeometry geometry ;
BEGIN
-- RAISE WARNING '%',place;
2012-05-22 18:27:42 +04:00
NEWgeometry : = ST_PointOnSurface ( place ) ;
RETURN ( partition * 1000000 ) + ( 500 - ST_X ( NEWgeometry ) : : integer ) * 1000 + ( 500 - ST_Y ( NEWgeometry ) : : integer ) ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
CREATE OR REPLACE FUNCTION transliteration ( text ) RETURNS text
2010-10-27 18:05:42 +04:00
AS ' {modulepath}/nominatim.so ' , ' transliteration '
2010-10-24 03:12:37 +04:00
LANGUAGE c IMMUTABLE STRICT ;
CREATE OR REPLACE FUNCTION gettokenstring ( text ) RETURNS text
2010-10-27 18:05:42 +04:00
AS ' {modulepath}/nominatim.so ' , ' gettokenstring '
2010-10-24 03:12:37 +04:00
LANGUAGE c IMMUTABLE STRICT ;
CREATE OR REPLACE FUNCTION make_standard_name ( name TEXT ) RETURNS TEXT
AS $ $
DECLARE
o TEXT ;
BEGIN
2018-08-02 00:12:34 +03:00
o : = public . gettokenstring ( public . transliteration ( name ) ) ;
2010-10-24 03:12:37 +04:00
RETURN trim ( substr ( o , 1 , length ( o ) ) ) ;
END ;
$ $
LANGUAGE ' plpgsql ' IMMUTABLE ;
2012-09-25 02:36:34 +04:00
-- returns NULL if the word is too common
2010-10-24 03:12:37 +04:00
CREATE OR REPLACE FUNCTION getorcreate_word_id ( lookup_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
2012-09-25 02:36:34 +04:00
count INTEGER ;
2010-10-24 03:12:37 +04:00
BEGIN
lookup_token : = trim ( lookup_word ) ;
2012-09-25 02:36:34 +04:00
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 ;
2010-10-24 03:12:37 +04:00
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2013-04-10 00:44:05 +04:00
INSERT INTO word VALUES ( return_word_id , lookup_token , null , null , null , null , 0 ) ;
2012-09-25 02:36:34 +04:00
ELSE
IF count > get_maxwordfreq ( ) THEN
return_word_id : = NULL ;
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION getorcreate_housenumber_id ( lookup_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and class = ' place ' and type = ' house ' into return_word_id ;
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2013-04-10 00:44:05 +04:00
INSERT INTO word VALUES ( return_word_id , lookup_token , null , ' place ' , ' house ' , null , 0 ) ;
2010-10-24 03:12:37 +04:00
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
2017-07-03 23:13:01 +03:00
CREATE OR REPLACE FUNCTION getorcreate_postcode_id ( postcode TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
lookup_word TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_word : = upper ( trim ( postcode ) ) ;
lookup_token : = ' ' | | make_standard_name ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and class = ' place ' and type = ' postcode ' into return_word_id ;
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
INSERT INTO word VALUES ( return_word_id , lookup_token , lookup_word , ' place ' , ' postcode ' , null , 0 ) ;
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
2010-10-24 03:12:37 +04:00
CREATE OR REPLACE FUNCTION getorcreate_country ( lookup_word TEXT , lookup_country_code varchar ( 2 ) )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and country_code = lookup_country_code into return_word_id ;
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2013-04-10 00:44:05 +04:00
INSERT INTO word VALUES ( return_word_id , lookup_token , null , null , null , lookup_country_code , 0 ) ;
2010-10-24 03:12:37 +04:00
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
2017-06-01 20:34:16 +03:00
CREATE OR REPLACE FUNCTION getorcreate_amenity ( lookup_word TEXT , normalized_word TEXT , lookup_class text , lookup_type text )
2010-10-24 03:12:37 +04:00
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
2017-06-01 20:34:16 +03:00
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 ;
2010-10-24 03:12:37 +04:00
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2017-06-01 20:34:16 +03:00
INSERT INTO word VALUES ( return_word_id , lookup_token , normalized_word , lookup_class , lookup_type , null , 0 ) ;
2010-10-24 03:12:37 +04:00
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
2017-06-01 20:34:16 +03:00
CREATE OR REPLACE FUNCTION getorcreate_amenityoperator ( lookup_word TEXT , normalized_word TEXT , lookup_class text , lookup_type text , op text )
2010-10-24 03:12:37 +04:00
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
2017-06-01 20:34:16 +03:00
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 ;
2010-10-24 03:12:37 +04:00
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2017-06-01 20:34:16 +03:00
INSERT INTO word VALUES ( return_word_id , lookup_token , normalized_word , lookup_class , lookup_type , null , 0 , op ) ;
2010-10-24 03:12:37 +04:00
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION getorcreate_name_id ( lookup_word TEXT , src_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
nospace_lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id ;
IF return_word_id IS NULL THEN
return_word_id : = nextval ( ' seq_word ' ) ;
2013-04-10 00:44:05 +04:00
INSERT INTO word VALUES ( return_word_id , lookup_token , src_word , null , null , null , 0 ) ;
2010-10-24 03:12:37 +04:00
-- nospace_lookup_token := replace(replace(lookup_token, '-',''), ' ','');
-- IF ' '||nospace_lookup_token != lookup_token THEN
-- INSERT INTO word VALUES (return_word_id, '-'||nospace_lookup_token, null, src_word, null, null, null, 0, null);
-- END IF;
END IF ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION getorcreate_name_id ( lookup_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
BEGIN
RETURN getorcreate_name_id ( lookup_word , ' ' ) ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION get_word_id ( lookup_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = trim ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
CREATE OR REPLACE FUNCTION get_name_id ( lookup_word TEXT )
RETURNS INTEGER
AS $ $
DECLARE
lookup_token TEXT ;
return_word_id INTEGER ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
SELECT min ( word_id ) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_id ;
RETURN return_word_id ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2014-04-28 22:01:44 +04:00
CREATE OR REPLACE FUNCTION get_name_ids ( lookup_word TEXT )
RETURNS INTEGER [ ]
AS $ $
DECLARE
lookup_token TEXT ;
return_word_ids INTEGER [ ] ;
BEGIN
lookup_token : = ' ' | | trim ( lookup_word ) ;
SELECT array_agg ( word_id ) FROM word WHERE word_token = lookup_token and class is null and type is null into return_word_ids ;
RETURN return_word_ids ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2010-10-24 03:12:37 +04:00
CREATE OR REPLACE FUNCTION array_merge ( a INTEGER [ ] , b INTEGER [ ] )
RETURNS INTEGER [ ]
AS $ $
DECLARE
i INTEGER ;
r INTEGER [ ] ;
BEGIN
IF array_upper ( a , 1 ) IS NULL THEN
RETURN b ;
END IF ;
IF array_upper ( b , 1 ) IS NULL THEN
RETURN a ;
END IF ;
r : = a ;
FOR i IN 1 . . array_upper ( b , 1 ) LOOP
2012-01-21 14:21:42 +04:00
IF NOT ( ARRAY [ b [ i ] ] < @ r ) THEN
2010-10-24 03:12:37 +04:00
r : = r | | b [ i ] ;
END IF ;
END LOOP ;
RETURN r ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2018-08-04 19:44:17 +03:00
CREATE OR REPLACE FUNCTION reverse_place_diameter ( rank_search SMALLINT )
RETURNS FLOAT
AS $ $
BEGIN
IF rank_search < = 4 THEN
RETURN 5 . 0 ;
ELSIF rank_search < = 8 THEN
RETURN 1 . 8 ;
ELSIF rank_search < = 12 THEN
RETURN 0 . 6 ;
ELSIF rank_search < = 17 THEN
RETURN 0 . 16 ;
ELSIF rank_search < = 18 THEN
RETURN 0 . 08 ;
ELSIF rank_search < = 19 THEN
RETURN 0 . 04 ;
END IF ;
RETURN 0 . 02 ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2017-06-29 22:39:00 +03:00
CREATE OR REPLACE FUNCTION get_postcode_rank ( country_code VARCHAR ( 2 ) , postcode TEXT ,
OUT rank_search SMALLINT , OUT rank_address SMALLINT )
AS $ $
DECLARE
part TEXT ;
BEGIN
rank_search : = 30 ;
rank_address : = 30 ;
2017-07-07 00:54:07 +03:00
postcode : = upper ( postcode ) ;
2017-06-29 22:39:00 +03:00
IF country_code = ' gb ' THEN
IF postcode ~ ' ^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$ ' THEN
rank_search : = 25 ;
rank_address : = 5 ;
ELSEIF postcode ~ ' ^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$ ' THEN
rank_search : = 23 ;
rank_address : = 5 ;
ELSEIF postcode ~ ' ^([A-Z][A-Z]?[0-9][0-9A-Z])$ ' THEN
rank_search : = 21 ;
rank_address : = 5 ;
END IF ;
ELSEIF country_code = ' sg ' THEN
IF postcode ~ ' ^([0-9]{6})$ ' THEN
rank_search : = 25 ;
rank_address : = 11 ;
END IF ;
ELSEIF country_code = ' de ' THEN
IF postcode ~ ' ^([0-9]{5})$ ' THEN
rank_search : = 21 ;
rank_address : = 11 ;
END IF ;
ELSE
-- Guess at the postcode format and coverage (!)
IF postcode ~ ' ^[A-Z0-9]{1,5}$ ' THEN -- Probably too short to be very local
rank_search : = 21 ;
rank_address : = 11 ;
ELSE
-- Does it look splitable into and area and local code?
part : = substring ( postcode from ' ^([- :A-Z0-9]+)([- :][A-Z0-9]+)$ ' ) ;
IF part IS NOT NULL THEN
rank_search : = 25 ;
rank_address : = 11 ;
ELSEIF postcode ~ ' ^[- :A-Z0-9]{6,}$ ' THEN
rank_search : = 21 ;
rank_address : = 11 ;
END IF ;
END IF ;
END IF ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2017-07-01 23:49:24 +03:00
-- Find the nearest artificial postcode for the given geometry.
-- TODO For areas there should not be more than two inside the geometry.
CREATE OR REPLACE FUNCTION get_nearest_postcode ( country VARCHAR ( 2 ) , geom GEOMETRY ) RETURNS TEXT
AS $ $
DECLARE
2017-07-16 20:49:47 +03:00
outcode TEXT ;
cnt INTEGER ;
2017-07-01 23:49:24 +03:00
BEGIN
2017-07-09 18:29:48 +03:00
-- If the geometry is an area then only one postcode must be within
-- that area, otherwise consider the area as not having a postcode.
IF ST_GeometryType ( geom ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
2017-07-16 20:49:47 +03:00
SELECT min ( postcode ) , count ( * ) FROM
2017-07-09 18:29:48 +03:00
( SELECT postcode FROM location_postcode
WHERE ST_Contains ( geom , location_postcode . geometry ) LIMIT 2 ) sub
2017-07-16 20:49:47 +03:00
INTO outcode , cnt ;
IF cnt = 1 THEN
RETURN outcode ;
ELSE
RETURN null ;
END IF ;
2017-07-09 18:29:48 +03:00
END IF ;
2017-07-16 20:49:47 +03:00
SELECT postcode FROM location_postcode
WHERE ST_DWithin ( geom , location_postcode . geometry , 0 . 05 )
AND location_postcode . country_code = country
ORDER BY ST_Distance ( geom , location_postcode . geometry ) LIMIT 1
INTO outcode ;
2017-07-01 23:49:24 +03:00
2017-07-16 20:49:47 +03:00
RETURN outcode ;
2017-07-01 23:49:24 +03:00
END ;
$ $
LANGUAGE plpgsql ;
2017-06-29 22:39:00 +03:00
2012-10-08 02:05:23 +04:00
CREATE OR REPLACE FUNCTION create_country ( src HSTORE , lookup_country_code varchar ( 2 ) ) RETURNS VOID
AS $ $
DECLARE
s TEXT ;
w INTEGER ;
words TEXT [ ] ;
item RECORD ;
j INTEGER ;
BEGIN
FOR item IN SELECT ( each ( src ) ) . * LOOP
s : = make_standard_name ( item . value ) ;
w : = getorcreate_country ( s , lookup_country_code ) ;
words : = regexp_split_to_array ( item . value , E ' [,;()] ' ) ;
IF array_upper ( words , 1 ) ! = 1 THEN
FOR j IN 1 . . array_upper ( words , 1 ) LOOP
s : = make_standard_name ( words [ j ] ) ;
IF s ! = ' ' THEN
w : = getorcreate_country ( s , lookup_country_code ) ;
END IF ;
END LOOP ;
END IF ;
END LOOP ;
END ;
$ $
LANGUAGE plpgsql ;
2010-10-24 03:12:37 +04:00
CREATE OR REPLACE FUNCTION make_keywords ( src HSTORE ) RETURNS INTEGER [ ]
AS $ $
DECLARE
result INTEGER [ ] ;
s TEXT ;
w INTEGER ;
words TEXT [ ] ;
item RECORD ;
j INTEGER ;
BEGIN
result : = ' {} ' : : INTEGER [ ] ;
FOR item IN SELECT ( each ( src ) ) . * LOOP
s : = make_standard_name ( item . value ) ;
w : = getorcreate_name_id ( s , item . value ) ;
2012-01-21 14:21:42 +04:00
IF not ( ARRAY [ w ] < @ result ) THEN
result : = result | | w ;
END IF ;
2010-10-24 03:12:37 +04:00
2013-02-08 22:11:15 +04:00
w : = getorcreate_word_id ( s ) ;
2013-10-31 00:09:21 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2013-02-08 22:11:15 +04:00
result : = result | | w ;
END IF ;
2010-10-24 03:12:37 +04:00
words : = string_to_array ( s , ' ' ) ;
IF array_upper ( words , 1 ) IS NOT NULL THEN
FOR j IN 1 . . array_upper ( words , 1 ) LOOP
IF ( words [ j ] ! = ' ' ) THEN
w = getorcreate_word_id ( words [ j ] ) ;
2012-09-25 02:36:34 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2012-01-21 14:21:42 +04:00
result : = result | | w ;
2010-10-24 03:12:37 +04:00
END IF ;
END IF ;
END LOOP ;
END IF ;
words : = regexp_split_to_array ( item . value , E ' [,;()] ' ) ;
IF array_upper ( words , 1 ) ! = 1 THEN
FOR j IN 1 . . array_upper ( words , 1 ) LOOP
s : = make_standard_name ( words [ j ] ) ;
IF s ! = ' ' THEN
w : = getorcreate_word_id ( s ) ;
2012-09-25 02:36:34 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2012-01-21 14:21:42 +04:00
result : = result | | w ;
2010-10-24 03:12:37 +04:00
END IF ;
END IF ;
END LOOP ;
END IF ;
s : = regexp_replace ( item . value , ' 市$ ' , ' ' ) ;
IF s ! = item . value THEN
s : = make_standard_name ( s ) ;
IF s ! = ' ' THEN
w : = getorcreate_name_id ( s , item . value ) ;
2012-01-21 14:21:42 +04:00
IF NOT ( ARRAY [ w ] < @ result ) THEN
result : = result | | w ;
2010-10-24 03:12:37 +04:00
END IF ;
END IF ;
END IF ;
END LOOP ;
RETURN result ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
CREATE OR REPLACE FUNCTION make_keywords ( src TEXT ) RETURNS INTEGER [ ]
AS $ $
DECLARE
result INTEGER [ ] ;
s TEXT ;
w INTEGER ;
words TEXT [ ] ;
i INTEGER ;
j INTEGER ;
BEGIN
result : = ' {} ' : : INTEGER [ ] ;
s : = make_standard_name ( src ) ;
2012-05-13 11:15:56 +04:00
w : = getorcreate_name_id ( s , src ) ;
2010-10-24 03:12:37 +04:00
2012-01-21 14:21:42 +04:00
IF NOT ( ARRAY [ w ] < @ result ) THEN
2010-10-24 03:12:37 +04:00
result : = result | | w ;
END IF ;
2013-02-08 22:11:15 +04:00
w : = getorcreate_word_id ( s ) ;
2013-10-31 00:09:21 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2013-02-08 22:11:15 +04:00
result : = result | | w ;
END IF ;
2010-10-24 03:12:37 +04:00
words : = string_to_array ( s , ' ' ) ;
IF array_upper ( words , 1 ) IS NOT NULL THEN
FOR j IN 1 . . array_upper ( words , 1 ) LOOP
IF ( words [ j ] ! = ' ' ) THEN
w = getorcreate_word_id ( words [ j ] ) ;
2012-09-25 02:36:34 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2010-10-24 03:12:37 +04:00
result : = result | | w ;
END IF ;
END IF ;
END LOOP ;
END IF ;
2012-05-13 11:15:56 +04:00
words : = regexp_split_to_array ( src , E ' [,;()] ' ) ;
IF array_upper ( words , 1 ) ! = 1 THEN
FOR j IN 1 . . array_upper ( words , 1 ) LOOP
s : = make_standard_name ( words [ j ] ) ;
IF s ! = ' ' THEN
w : = getorcreate_word_id ( s ) ;
2012-09-25 02:36:34 +04:00
IF w IS NOT NULL AND NOT ( ARRAY [ w ] < @ result ) THEN
2012-05-13 11:15:56 +04:00
result : = result | | w ;
END IF ;
END IF ;
END LOOP ;
END IF ;
s : = regexp_replace ( src , ' 市$ ' , ' ' ) ;
IF s ! = src THEN
s : = make_standard_name ( s ) ;
IF s ! = ' ' THEN
w : = getorcreate_name_id ( s , src ) ;
IF NOT ( ARRAY [ w ] < @ result ) THEN
result : = result | | w ;
END IF ;
END IF ;
END IF ;
2010-10-24 03:12:37 +04:00
RETURN result ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
CREATE OR REPLACE FUNCTION get_country_code ( place geometry ) RETURNS TEXT
AS $ $
DECLARE
place_centre GEOMETRY ;
nearcountry RECORD ;
BEGIN
2012-05-11 21:23:44 +04:00
place_centre : = ST_PointOnSurface ( place ) ;
2010-10-24 03:12:37 +04:00
2017-06-16 00:08:58 +03:00
-- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
2010-10-26 19:22:41 +04:00
2013-05-11 23:36:36 +04:00
-- Try for a OSM polygon
2019-07-09 21:47:25 +03:00
FOR nearcountry IN select country_code from location_area_country where country_code is not null and st_covers ( geometry , place_centre ) limit 1
2013-05-11 23:36:36 +04:00
LOOP
RETURN nearcountry . country_code ;
END LOOP ;
2017-06-16 00:08:58 +03:00
-- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
2012-05-22 18:27:42 +04:00
-- Try for OSM fallback data
-- The order is to deal with places like HongKong that are 'states' within another polygon
FOR nearcountry IN select country_code from country_osm_grid where st_covers ( geometry , place_centre ) order by area asc limit 1
2010-10-24 03:12:37 +04:00
LOOP
RETURN nearcountry . country_code ;
END LOOP ;
2017-06-16 00:08:58 +03:00
-- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
2012-05-22 18:27:42 +04:00
--
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
2010-11-09 13:19:36 +03:00
LOOP
RETURN nearcountry . country_code ;
END LOOP ;
2010-10-24 03:12:37 +04:00
RETURN NULL ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
CREATE OR REPLACE FUNCTION get_country_language_code ( search_country_code VARCHAR ( 2 ) ) RETURNS TEXT
AS $ $
DECLARE
nearcountry RECORD ;
BEGIN
2010-11-09 13:19:36 +03:00
FOR nearcountry IN select distinct country_default_language_code from country_name where country_code = search_country_code limit 1
2010-10-24 03:12:37 +04:00
LOOP
RETURN lower ( nearcountry . country_default_language_code ) ;
END LOOP ;
RETURN NULL ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2012-12-12 06:09:18 +04:00
CREATE OR REPLACE FUNCTION get_country_language_codes ( search_country_code VARCHAR ( 2 ) ) RETURNS TEXT [ ]
AS $ $
DECLARE
nearcountry RECORD ;
BEGIN
FOR nearcountry IN select country_default_language_codes from country_name where country_code = search_country_code limit 1
LOOP
RETURN lower ( nearcountry . country_default_language_codes ) ;
END LOOP ;
RETURN NULL ;
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2014-04-11 00:55:49 +04:00
CREATE OR REPLACE FUNCTION get_partition ( in_country_code VARCHAR ( 10 ) ) RETURNS INTEGER
2010-11-01 18:09:10 +03:00
AS $ $
DECLARE
nearcountry RECORD ;
BEGIN
2010-11-09 13:19:36 +03:00
FOR nearcountry IN select partition from country_name where country_code = in_country_code
2010-11-01 18:09:10 +03:00
LOOP
2010-11-09 13:19:36 +03:00
RETURN nearcountry . partition ;
2010-11-01 18:09:10 +03:00
END LOOP ;
2010-11-09 13:19:36 +03:00
RETURN 0 ;
2010-11-01 18:09:10 +03:00
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2011-06-14 17:42:46 +04:00
CREATE OR REPLACE FUNCTION delete_location ( OLD_place_id BIGINT ) RETURNS BOOLEAN
2010-10-24 03:12:37 +04:00
AS $ $
DECLARE
BEGIN
DELETE FROM location_area where place_id = OLD_place_id ;
-- TODO:location_area
RETURN true ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION add_location (
2011-06-14 17:42:46 +04:00
place_id BIGINT ,
2010-11-01 18:09:10 +03:00
country_code varchar ( 2 ) ,
2010-11-09 13:19:36 +03:00
partition INTEGER ,
2010-11-01 18:09:10 +03:00
keywords INTEGER [ ] ,
2010-10-24 03:12:37 +04:00
rank_search INTEGER ,
rank_address INTEGER ,
2017-07-01 20:02:25 +03:00
in_postcode TEXT ,
2010-10-24 03:12:37 +04:00
geometry GEOMETRY
)
RETURNS BOOLEAN
AS $ $
DECLARE
locationid INTEGER ;
2010-10-26 19:22:41 +04:00
centroid GEOMETRY ;
2010-10-24 03:12:37 +04:00
diameter FLOAT ;
2010-10-26 19:22:41 +04:00
x BOOLEAN ;
2012-05-22 18:27:42 +04:00
splitGeom RECORD ;
secgeo GEOMETRY ;
2017-07-01 20:02:25 +03:00
postcode TEXT ;
2010-10-24 03:12:37 +04:00
BEGIN
2010-11-17 18:19:25 +03:00
IF rank_search > 25 THEN
RAISE EXCEPTION ' Adding location with rank > 25 (% rank %) ' , place_id , rank_search ;
2010-11-01 18:09:10 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2013-01-22 11:01:30 +04:00
x : = deleteLocationArea ( partition , place_id , rank_search ) ;
2010-10-24 03:12:37 +04:00
2017-07-01 20:02:25 +03:00
-- add postcode only if it contains a single entry, i.e. ignore postcode lists
2017-07-02 12:32:32 +03:00
postcode : = NULL ;
IF in_postcode is not null AND in_postcode not similar to ' %(,|;)% ' THEN
2017-07-03 23:13:01 +03:00
postcode : = upper ( trim ( in_postcode ) ) ;
2017-07-01 20:02:25 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2017-07-01 20:02:25 +03:00
IF ST_GeometryType ( geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
2010-11-01 18:09:10 +03:00
centroid : = ST_Centroid ( geometry ) ;
2010-10-24 03:12:37 +04:00
2012-05-24 02:25:15 +04:00
FOR secgeo IN select split_geometry ( geometry ) AS geom LOOP
2017-07-01 20:02:25 +03:00
x : = insertLocationAreaLarge ( partition , place_id , country_code , keywords , rank_search , rank_address , false , postcode , centroid , secgeo ) ;
2012-05-22 18:27:42 +04:00
END LOOP ;
2010-10-24 03:12:37 +04:00
2015-03-31 00:43:27 +03:00
ELSE
2010-10-26 19:22:41 +04:00
2010-11-01 18:09:10 +03:00
diameter : = 0 . 02 ;
2010-12-07 16:41:02 +03:00
IF rank_address = 0 THEN
diameter : = 0 . 02 ;
ELSEIF rank_search < = 14 THEN
diameter : = 1 . 2 ;
ELSEIF rank_search < = 15 THEN
2010-11-01 18:09:10 +03:00
diameter : = 1 ;
2010-12-07 16:41:02 +03:00
ELSEIF rank_search < = 16 THEN
2010-11-01 18:09:10 +03:00
diameter : = 0 . 5 ;
2010-12-07 16:41:02 +03:00
ELSEIF rank_search < = 17 THEN
diameter : = 0 . 2 ;
ELSEIF rank_search < = 21 THEN
2010-11-01 18:09:10 +03:00
diameter : = 0 . 05 ;
ELSEIF rank_search = 25 THEN
diameter : = 0 . 005 ;
2010-10-26 19:22:41 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
2011-01-05 17:07:26 +03:00
-- RAISE WARNING 'adding % diameter %', place_id, diameter;
2010-12-07 16:41:02 +03:00
2010-11-01 18:09:10 +03:00
secgeo : = ST_Buffer ( geometry , diameter ) ;
2017-07-01 20:02:25 +03:00
x : = insertLocationAreaLarge ( partition , place_id , country_code , keywords , rank_search , rank_address , true , postcode , ST_Centroid ( geometry ) , secgeo ) ;
2010-11-01 18:09:10 +03:00
2010-10-24 03:12:37 +04:00
END IF ;
2010-11-01 18:09:10 +03:00
RETURN true ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql ;
2016-04-25 10:44:01 +03:00
-- find the parent road of the cut road parts
2015-02-17 02:00:36 +03:00
CREATE OR REPLACE FUNCTION get_interpolation_parent ( wayid BIGINT , street TEXT , place TEXT ,
partition INTEGER , centroid GEOMETRY , geom GEOMETRY )
RETURNS BIGINT AS $ $
DECLARE
addr_street TEXT ;
addr_place TEXT ;
parent_place_id BIGINT ;
address_street_word_ids INTEGER [ ] ;
waynodes BIGINT [ ] ;
location RECORD ;
BEGIN
addr_street = street ;
addr_place = place ;
IF addr_street is null and addr_place is null THEN
select nodes from planet_osm_ways where id = wayid INTO waynodes ;
2017-04-02 16:19:39 +03:00
FOR location IN SELECT placex . address from placex
2015-02-19 02:38:54 +03:00
where osm_type = ' N ' and osm_id = ANY ( waynodes )
2017-04-02 16:19:39 +03:00
and placex . address is not null
and ( placex . address ? ' street ' or placex . address ? ' place ' )
2015-02-17 02:00:36 +03:00
and indexed_status < 100
limit 1 LOOP
2017-04-02 16:19:39 +03:00
addr_street = location . address - > ' street ' ;
addr_place = location . address - > ' place ' ;
2015-02-17 02:00:36 +03:00
END LOOP ;
END IF ;
IF addr_street IS NOT NULL THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( addr_street ) ) ;
IF address_street_word_ids IS NOT NULL THEN
FOR location IN SELECT place_id from getNearestNamedRoadFeature ( partition , centroid , address_street_word_ids ) LOOP
parent_place_id : = location . place_id ;
END LOOP ;
END IF ;
END IF ;
IF parent_place_id IS NULL AND addr_place IS NOT NULL THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( addr_place ) ) ;
IF address_street_word_ids IS NOT NULL THEN
FOR location IN SELECT place_id from getNearestNamedPlaceFeature ( partition , centroid , address_street_word_ids ) LOOP
parent_place_id : = location . place_id ;
END LOOP ;
END IF ;
END IF ;
IF parent_place_id is null THEN
FOR location IN SELECT place_id FROM placex
WHERE ST_DWithin ( geom , placex . geometry , 0 . 001 ) and placex . rank_search = 26
ORDER BY ( ST_distance ( placex . geometry , ST_LineInterpolatePoint ( geom , 0 ) ) +
ST_distance ( placex . geometry , ST_LineInterpolatePoint ( geom , 0 . 5 ) ) +
ST_distance ( placex . geometry , ST_LineInterpolatePoint ( geom , 1 ) ) ) ASC limit 1
LOOP
parent_place_id : = location . place_id ;
END LOOP ;
END IF ;
2015-02-19 02:38:54 +03:00
IF parent_place_id is null THEN
RETURN 0 ;
END IF ;
2015-02-17 02:00:36 +03:00
RETURN parent_place_id ;
END ;
$ $
LANGUAGE plpgsql ;
2010-10-24 03:12:37 +04:00
2019-07-04 00:15:54 +03:00
CREATE OR REPLACE FUNCTION osmline_reinsert ( node_id BIGINT , geom GEOMETRY )
RETURNS BOOLEAN
AS $ $
DECLARE
existingline RECORD ;
BEGIN
SELECT w . id FROM planet_osm_ways w , location_property_osmline p
WHERE p . linegeo & & geom and p . osm_id = w . id and p . indexed_status = 0
and node_id = any ( w . nodes ) INTO existingline ;
IF existingline . id is not NULL THEN
DELETE FROM location_property_osmline WHERE osm_id = existingline . id ;
INSERT INTO location_property_osmline ( osm_id , address , linegeo )
SELECT osm_id , address , geometry FROM place
WHERE osm_type = ' W ' and osm_id = existingline . id ;
END IF ;
RETURN true ;
END ;
$ $
LANGUAGE plpgsql ;
2016-04-25 10:44:01 +03:00
2017-02-26 14:58:07 +03:00
CREATE OR REPLACE FUNCTION osmline_insert ( ) RETURNS TRIGGER
AS $ $
2010-10-24 03:12:37 +04:00
BEGIN
2017-02-26 14:58:07 +03:00
NEW . place_id : = nextval ( ' seq_place ' ) ;
NEW . indexed_date : = now ( ) ;
2014-10-03 23:55:18 +04:00
2017-02-26 14:58:07 +03:00
IF NEW . indexed_status IS NULL THEN
2017-03-26 22:19:52 +03:00
IF NEW . address is NULL OR NOT NEW . address ? ' interpolation '
2017-03-26 01:11:09 +03:00
OR NEW . address - > ' interpolation ' NOT IN ( ' odd ' , ' even ' , ' all ' ) THEN
-- other interpolation types than odd/even/all (e.g. numeric ones) are not supported
RETURN NULL ;
2016-04-25 10:44:01 +03:00
END IF ;
2014-10-03 23:55:18 +04:00
2017-02-26 14:58:07 +03:00
NEW . indexed_status : = 1 ; - - STATUS_NEW
2017-03-26 01:11:09 +03:00
NEW . country_code : = lower ( get_country_code ( NEW . linegeo ) ) ;
2014-10-03 23:55:18 +04:00
2017-03-26 01:11:09 +03:00
NEW . partition : = get_partition ( NEW . country_code ) ;
2017-02-26 14:58:07 +03:00
NEW . geometry_sector : = geometry_sector ( NEW . partition , NEW . linegeo ) ;
END IF ;
2010-10-24 03:12:37 +04:00
2017-02-26 14:58:07 +03:00
RETURN NEW ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql ;
2016-04-25 10:44:01 +03:00
2010-10-24 03:12:37 +04:00
CREATE OR REPLACE FUNCTION placex_insert ( ) RETURNS TRIGGER
AS $ $
DECLARE
i INTEGER ;
postcode TEXT ;
result BOOLEAN ;
2018-11-24 01:02:32 +03:00
is_area BOOLEAN ;
2010-10-24 03:12:37 +04:00
country_code VARCHAR ( 2 ) ;
2010-11-09 13:19:36 +03:00
default_language VARCHAR ( 10 ) ;
2010-10-24 03:12:37 +04:00
diameter FLOAT ;
2012-02-19 14:33:21 +04:00
classtable TEXT ;
2018-11-24 01:02:32 +03:00
classtype TEXT ;
2010-10-24 03:12:37 +04:00
BEGIN
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' % % % % ' , NEW . osm_type , NEW . osm_id , NEW . class , NEW . type ;
2010-10-24 03:12:37 +04:00
NEW . place_id : = nextval ( ' seq_place ' ) ;
2010-11-01 18:09:10 +03:00
NEW . indexed_status : = 1 ; - - STATUS_NEW
2017-03-26 01:11:09 +03:00
NEW . country_code : = lower ( get_country_code ( NEW . geometry ) ) ;
2012-04-16 01:05:31 +04:00
2017-03-26 01:11:09 +03:00
NEW . partition : = get_partition ( NEW . country_code ) ;
2010-11-09 13:19:36 +03:00
NEW . geometry_sector : = geometry_sector ( NEW . partition , NEW . geometry ) ;
-- copy 'name' to or from the default language (if there is a default language)
2012-03-30 02:52:08 +04:00
IF NEW . name is not null AND array_upper ( akeys ( NEW . name ) , 1 ) > 1 THEN
2017-03-26 01:11:09 +03:00
default_language : = get_country_language_code ( NEW . country_code ) ;
2010-11-09 13:19:36 +03:00
IF default_language IS NOT NULL THEN
IF NEW . name ? ' name ' AND NOT NEW . name ? ( ' name: ' | | default_language ) THEN
2012-11-01 05:47:30 +04:00
NEW . name : = NEW . name | | hstore ( ( ' name: ' | | default_language ) , ( NEW . name - > ' name ' ) ) ;
2010-11-09 13:19:36 +03:00
ELSEIF NEW . name ? ( ' name: ' | | default_language ) AND NOT NEW . name ? ' name ' THEN
2012-11-01 05:47:30 +04:00
NEW . name : = NEW . name | | hstore ( ' name ' , ( NEW . name - > ( ' name: ' | | default_language ) ) ) ;
2010-11-09 13:19:36 +03:00
END IF ;
END IF ;
END IF ;
2010-10-24 03:12:37 +04:00
IF NEW . osm_type = ' X ' THEN
-- E'X'ternal records should already be in the right format so do nothing
ELSE
2018-11-24 01:02:32 +03:00
is_area : = ST_GeometryType ( NEW . geometry ) IN ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) ;
2010-10-24 03:12:37 +04:00
2018-11-24 01:02:32 +03:00
IF NEW . class in ( ' place ' , ' boundary ' )
AND NEW . type in ( ' postcode ' , ' postal_code ' ) THEN
2012-03-22 04:33:28 +04:00
2018-11-24 01:02:32 +03:00
IF NEW . address IS NULL OR NOT NEW . address ? ' postcode ' THEN
-- most likely just a part of a multipolygon postcode boundary, throw it away
RETURN NULL ;
END IF ;
2014-09-11 21:42:52 +04:00
2018-11-24 01:02:32 +03:00
NEW . name : = hstore ( ' ref ' , NEW . address - > ' postcode ' ) ;
2012-03-22 04:33:28 +04:00
2018-11-24 01:02:32 +03:00
SELECT * FROM get_postcode_rank ( NEW . country_code , NEW . address - > ' postcode ' )
INTO NEW . rank_search , NEW . rank_address ;
2018-07-22 17:22:07 +03:00
2018-11-24 01:02:32 +03:00
IF NOT is_area THEN
NEW . rank_address : = 0 ;
2010-10-24 03:12:37 +04:00
END IF ;
2018-11-24 01:02:32 +03:00
ELSEIF NEW . class = ' boundary ' AND NOT is_area THEN
2010-12-07 16:41:02 +03:00
return NULL ;
2019-01-26 15:34:28 +03:00
ELSEIF NEW . class = ' boundary ' AND NEW . type = ' administrative '
AND NEW . admin_level < = 4 AND NEW . osm_type = ' W ' THEN
return NULL ;
2018-11-24 01:02:32 +03:00
ELSEIF NEW . class = ' railway ' AND NEW . type in ( ' rail ' ) THEN
return NULL ;
ELSEIF NEW . osm_type = ' N ' AND NEW . class = ' highway ' THEN
NEW . rank_search = 30 ;
NEW . rank_address = 0 ;
ELSEIF NEW . class = ' landuse ' AND NOT is_area THEN
NEW . rank_search = 30 ;
NEW . rank_address = 0 ;
ELSE
-- do table lookup stuff
IF NEW . class = ' boundary ' and NEW . type = ' administrative ' THEN
classtype = NEW . type | | NEW . admin_level : : TEXT ;
2013-10-15 23:10:46 +04:00
ELSE
2018-11-24 01:02:32 +03:00
classtype = NEW . type ;
2013-10-15 23:10:46 +04:00
END IF ;
2018-11-24 01:02:32 +03:00
SELECT l . rank_search , l . rank_address FROM address_levels l
WHERE ( l . country_code = NEW . country_code or l . country_code is NULL )
AND l . class = NEW . class AND ( l . type = classtype or l . type is NULL )
ORDER BY l . country_code , l . class , l . type LIMIT 1
INTO NEW . rank_search , NEW . rank_address ;
IF NEW . rank_search is NULL THEN
NEW . rank_search : = 30 ;
2014-10-08 22:47:32 +04:00
END IF ;
2018-11-24 01:02:32 +03:00
IF NEW . rank_address is NULL THEN
NEW . rank_address : = 30 ;
2014-05-08 00:46:23 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
2018-11-24 01:02:32 +03:00
-- some postcorrections
2019-06-20 00:16:43 +03:00
IF NEW . class = ' waterway ' AND NEW . osm_type = ' R ' THEN
2018-11-24 01:02:32 +03:00
-- Slightly promote waterway relations so that they are processed
-- before their members.
NEW . rank_search : = NEW . rank_search - 1 ;
END IF ;
2010-10-24 03:12:37 +04:00
2018-11-24 01:02:32 +03:00
IF ( NEW . extratags - > ' capital ' ) = ' yes ' THEN
NEW . rank_search : = NEW . rank_search - 1 ;
END IF ;
2010-10-24 03:12:37 +04:00
2012-05-11 21:23:44 +04:00
END IF ;
-- a country code make no sense below rank 4 (country)
2014-04-12 00:57:00 +04:00
IF NEW . rank_search < 4 THEN
2017-03-26 01:11:09 +03:00
NEW . country_code : = NULL ;
2010-12-07 16:41:02 +03:00
END IF ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_insert:END: % % % % ' , NEW . osm_type , NEW . osm_id , NEW . class , NEW . type ;
2016-04-07 22:47:51 +03:00
RETURN NEW ; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
2010-10-24 03:12:37 +04:00
2019-07-04 00:15:54 +03:00
IF NEW . osm_type = ' N ' and NEW . rank_search > 28 THEN
-- might be part of an interpolation
result : = osmline_reinsert ( NEW . osm_id , NEW . geometry ) ;
ELSEIF NEW . rank_address > 0 THEN
2014-04-12 00:57:00 +04:00
IF ( ST_GeometryType ( NEW . geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) AND ST_IsValid ( NEW . geometry ) ) THEN
-- Performance: We just can't handle re-indexing for country level changes
IF st_area ( NEW . geometry ) < 1 THEN
-- mark items within the geometry for re-indexing
-- RAISE WARNING 'placex poly insert: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
-- work around bug in postgis, this may have been fixed in 2.0.0 (see http://trac.osgeo.org/postgis/ticket/547)
update placex set indexed_status = 2 where ( st_covers ( NEW . geometry , placex . geometry ) OR ST_Intersects ( NEW . geometry , placex . geometry ) )
2017-04-05 23:19:42 +03:00
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 ' ) ) ;
2014-04-12 00:57:00 +04:00
update placex set indexed_status = 2 where ( st_covers ( NEW . geometry , placex . geometry ) OR ST_Intersects ( NEW . geometry , placex . geometry ) )
2017-04-05 23:19:42 +03:00
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 ' ) ) ;
2014-04-12 00:57:00 +04:00
END IF ;
ELSE
-- mark nearby items for re-indexing, where 'nearby' depends on the features rank_search and is a complete guess :(
2010-10-24 03:12:37 +04:00
diameter : = 0 ;
2014-04-12 00:57:00 +04:00
-- 16 = city, anything higher than city is effectively ignored (polygon required!)
IF NEW . type = ' postcode ' THEN
diameter : = 0 . 05 ;
ELSEIF NEW . rank_search < 16 THEN
diameter : = 0 ;
ELSEIF NEW . rank_search < 18 THEN
diameter : = 0 . 1 ;
ELSEIF NEW . rank_search < 20 THEN
diameter : = 0 . 05 ;
ELSEIF NEW . rank_search = 21 THEN
diameter : = 0 . 001 ;
ELSEIF NEW . rank_search < 24 THEN
diameter : = 0 . 02 ;
ELSEIF NEW . rank_search < 26 THEN
diameter : = 0 . 002 ; -- 100 to 200 meters
ELSEIF NEW . rank_search < 28 THEN
diameter : = 0 . 001 ; -- 50 to 100 meters
END IF ;
IF diameter > 0 THEN
-- RAISE WARNING 'placex point insert: % % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type,diameter;
IF NEW . rank_search > = 26 THEN
-- roads may cause reparenting for >27 rank places
update placex set indexed_status = 2 where indexed_status = 0 and rank_search > NEW . rank_search and ST_DWithin ( placex . geometry , NEW . geometry , diameter ) ;
2016-04-25 10:44:01 +03:00
-- reparenting also for OSM Interpolation Lines (and for Tiger?)
update location_property_osmline set indexed_status = 2 where indexed_status = 0 and ST_DWithin ( location_property_osmline . linegeo , NEW . geometry , diameter ) ;
2014-04-12 00:57:00 +04:00
ELSEIF NEW . rank_search > = 16 THEN
-- up to rank 16, street-less addresses may need reparenting
2017-04-05 23:19:42 +03:00
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 ' ) ;
2014-04-12 00:57:00 +04:00
ELSE
-- for all other places the search terms may change as well
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 ) ;
END IF ;
2012-12-16 14:54:46 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
END IF ;
2015-02-24 01:29:31 +03:00
2012-02-19 14:33:21 +04:00
-- add to tables for special search
-- Note: won't work on initial import because the classtype tables
-- do not yet exist. It won't hurt either.
classtable : = ' place_classtype_ ' | | NEW . class | | ' _ ' | | NEW . type ;
2013-11-23 16:31:29 +04:00
SELECT count ( * ) > 0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema ( ) INTO result ;
2012-02-19 14:33:21 +04:00
IF result THEN
EXECUTE ' INSERT INTO ' | | classtable : : regclass | | ' (place_id, centroid) VALUES ($1,$2) '
USING NEW . place_id , ST_Centroid ( NEW . geometry ) ;
END IF ;
2010-10-24 03:12:37 +04:00
RETURN NEW ;
END ;
$ $
LANGUAGE plpgsql ;
2016-04-25 10:44:01 +03:00
CREATE OR REPLACE FUNCTION osmline_update ( ) RETURNS
TRIGGER
AS $ $
DECLARE
place_centroid GEOMETRY ;
2017-02-26 14:58:07 +03:00
waynodes BIGINT [ ] ;
prevnode RECORD ;
nextnode RECORD ;
startnumber INTEGER ;
endnumber INTEGER ;
housenum INTEGER ;
linegeo GEOMETRY ;
splitline GEOMETRY ;
sectiongeo GEOMETRY ;
2017-07-06 21:42:03 +03:00
interpol_postcode TEXT ;
2017-02-26 14:58:07 +03:00
postcode TEXT ;
2016-04-25 10:44:01 +03:00
BEGIN
-- deferred delete
IF OLD . indexed_status = 100 THEN
delete from location_property_osmline where place_id = OLD . place_id ;
RETURN NULL ;
END IF ;
2016-05-15 15:24:43 +03:00
2016-04-25 10:44:01 +03:00
IF NEW . indexed_status ! = 0 OR OLD . indexed_status = 0 THEN
RETURN NEW ;
END IF ;
2016-05-15 15:24:43 +03:00
2017-04-02 16:19:39 +03:00
NEW . interpolationtype = NEW . address - > ' interpolation ' ;
2017-03-26 01:11:09 +03:00
2016-05-15 15:24:43 +03:00
place_centroid : = ST_PointOnSurface ( NEW . linegeo ) ;
2017-04-02 16:19:39 +03:00
NEW . parent_place_id = get_interpolation_parent ( NEW . osm_id , NEW . address - > ' street ' ,
NEW . address - > ' place ' ,
2016-05-15 15:24:43 +03:00
NEW . partition , place_centroid , NEW . linegeo ) ;
2017-02-26 14:58:07 +03:00
2017-07-06 21:42:03 +03:00
IF NEW . address is not NULL AND NEW . address ? ' postcode ' AND NEW . address - > ' postcode ' not similar to ' %(,|;)% ' THEN
interpol_postcode : = NEW . address - > ' postcode ' ;
housenum : = getorcreate_postcode_id ( NEW . address - > ' postcode ' ) ;
ELSE
interpol_postcode : = NULL ;
2017-02-26 14:58:07 +03:00
END IF ;
2017-04-02 16:19:39 +03:00
-- if the line was newly inserted, split the line as necessary
IF OLD . indexed_status = 1 THEN
2017-03-26 22:19:52 +03:00
select nodes from planet_osm_ways where id = NEW . osm_id INTO waynodes ;
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
IF array_upper ( waynodes , 1 ) IS NULL THEN
RETURN NEW ;
2017-02-26 14:58:07 +03:00
END IF ;
2017-03-26 22:19:52 +03:00
linegeo : = NEW . linegeo ;
startnumber : = NULL ;
FOR nodeidpos in 1 . . array_upper ( waynodes , 1 ) LOOP
select osm_id , address , geometry
from place where osm_type = ' N ' and osm_id = waynodes [ nodeidpos ] : : BIGINT
and address is not NULL and address ? ' housenumber ' limit 1 INTO nextnode ;
- - RAISE NOTICE ' Nextnode.place_id: %s ' , nextnode . place_id ;
IF nextnode . osm_id IS NOT NULL THEN
- - RAISE NOTICE ' place_id is not null ' ;
IF nodeidpos > 1 and nodeidpos < array_upper ( waynodes , 1 ) THEN
-- Make sure that the point is actually on the line. That might
-- be a bit paranoid but ensures that the algorithm still works
-- should osm2pgsql attempt to repair geometries.
splitline : = split_line_on_node ( linegeo , nextnode . geometry ) ;
sectiongeo : = ST_GeometryN ( splitline , 1 ) ;
linegeo : = ST_GeometryN ( splitline , 2 ) ;
ELSE
sectiongeo = linegeo ;
END IF ;
endnumber : = substring ( nextnode . address - > ' housenumber ' , ' [0-9]+ ' ) : : integer ;
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
IF startnumber IS NOT NULL AND endnumber IS NOT NULL
AND startnumber ! = endnumber
AND ST_GeometryType ( sectiongeo ) = ' ST_LineString ' THEN
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
IF ( startnumber > endnumber ) THEN
housenum : = endnumber ;
endnumber : = startnumber ;
startnumber : = housenum ;
sectiongeo : = ST_Reverse ( sectiongeo ) ;
END IF ;
2017-02-26 14:58:07 +03:00
2017-07-06 21:42:03 +03:00
-- determine postcode
postcode : = coalesce ( interpol_postcode ,
prevnode . address - > ' postcode ' ,
nextnode . address - > ' postcode ' ,
postcode ) ;
IF postcode is NULL THEN
SELECT placex . postcode FROM placex WHERE place_id = NEW . parent_place_id INTO postcode ;
END IF ;
IF postcode is NULL THEN
postcode : = get_nearest_postcode ( NEW . country_code , nextnode . geometry ) ;
END IF ;
2017-03-26 22:19:52 +03:00
IF NEW . startnumber IS NULL THEN
NEW . startnumber : = startnumber ;
NEW . endnumber : = endnumber ;
NEW . linegeo : = sectiongeo ;
2017-07-16 20:55:55 +03:00
NEW . postcode : = upper ( trim ( postcode ) ) ;
2017-03-26 22:19:52 +03:00
ELSE
insert into location_property_osmline
( linegeo , partition , osm_id , parent_place_id ,
startnumber , endnumber , interpolationtype ,
2017-04-02 16:19:39 +03:00
address , postcode , country_code ,
2017-03-26 22:19:52 +03:00
geometry_sector , indexed_status )
values ( sectiongeo , NEW . partition , NEW . osm_id , NEW . parent_place_id ,
startnumber , endnumber , NEW . interpolationtype ,
2017-07-06 21:42:03 +03:00
NEW . address , postcode ,
2017-03-26 22:19:52 +03:00
NEW . country_code , NEW . geometry_sector , 0 ) ;
END IF ;
END IF ;
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
-- early break if we are out of line string,
-- might happen when a line string loops back on itself
IF ST_GeometryType ( linegeo ) ! = ' ST_LineString ' THEN
RETURN NEW ;
END IF ;
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
startnumber : = substring ( nextnode . address - > ' housenumber ' , ' [0-9]+ ' ) : : integer ;
prevnode : = nextnode ;
END IF ;
END LOOP ;
END IF ;
2017-02-26 14:58:07 +03:00
2017-03-26 22:19:52 +03:00
-- marking descendants for reparenting is not needed, because there are
-- actually no descendants for interpolation lines
2017-02-26 14:58:07 +03:00
RETURN NEW ;
2016-04-25 10:44:01 +03:00
END ;
$ $
LANGUAGE plpgsql ;
2017-06-29 22:39:00 +03:00
-- Trigger for updates of location_postcode
--
-- Computes the parent object the postcode most likely refers to.
-- This will be the place that determines the address displayed when
-- searching for this postcode.
CREATE OR REPLACE FUNCTION postcode_update ( ) RETURNS
TRIGGER
AS $ $
DECLARE
partition SMALLINT ;
location RECORD ;
BEGIN
IF NEW . indexed_status ! = 0 OR OLD . indexed_status = 0 THEN
RETURN NEW ;
END IF ;
NEW . indexed_date = now ( ) ;
2017-02-26 14:58:07 +03:00
2017-06-29 22:39:00 +03:00
partition : = get_partition ( NEW . country_code ) ;
SELECT * FROM get_postcode_rank ( NEW . country_code , NEW . postcode )
INTO NEW . rank_search , NEW . rank_address ;
NEW . parent_place_id = 0 ;
FOR location IN
SELECT place_id
FROM getNearFeatures ( partition , NEW . geometry , NEW . rank_search , ' {} ' : : int [ ] )
WHERE NOT isguess ORDER BY rank_address DESC LIMIT 1
LOOP
NEW . parent_place_id = location . place_id ;
END LOOP ;
RETURN NEW ;
END ;
$ $
LANGUAGE plpgsql ;
2017-02-26 14:58:07 +03:00
2016-04-25 10:44:01 +03:00
CREATE OR REPLACE FUNCTION placex_update ( ) RETURNS
2010-10-24 03:12:37 +04:00
TRIGGER
AS $ $
DECLARE
place_centroid GEOMETRY ;
2019-06-10 19:23:12 +03:00
near_centroid GEOMETRY ;
2010-10-24 03:12:37 +04:00
search_maxdistance FLOAT [ ] ;
search_mindistance FLOAT [ ] ;
address_havelevel BOOLEAN [ ] ;
i INTEGER ;
iMax FLOAT ;
location RECORD ;
2011-01-05 17:07:26 +03:00
way RECORD ;
2010-10-24 03:12:37 +04:00
relation RECORD ;
2012-04-01 04:40:50 +04:00
relation_members TEXT [ ] ;
relMember RECORD ;
linkedplacex RECORD ;
2018-04-15 23:00:56 +03:00
addr_item RECORD ;
2010-10-24 03:12:37 +04:00
search_diameter FLOAT ;
search_prevdiameter FLOAT ;
search_maxrank INTEGER ;
address_maxrank INTEGER ;
address_street_word_id INTEGER ;
2014-04-28 22:01:44 +04:00
address_street_word_ids INTEGER [ ] ;
2011-06-14 17:42:46 +04:00
parent_place_id_rank BIGINT ;
2017-04-05 23:19:42 +03:00
addr_street TEXT ;
addr_place TEXT ;
2010-10-24 03:12:37 +04:00
isin TEXT [ ] ;
2010-10-26 19:22:41 +04:00
isin_tokens INT [ ] ;
location_rank_search INTEGER ;
location_distance FLOAT ;
2012-07-04 00:44:06 +04:00
location_parent GEOMETRY ;
location_isaddress BOOLEAN ;
2015-02-06 23:05:37 +03:00
location_keywords INTEGER [ ] ;
2010-10-24 03:12:37 +04:00
2012-03-22 04:33:28 +04:00
default_language TEXT ;
2010-10-24 03:12:37 +04:00
name_vector INTEGER [ ] ;
nameaddress_vector INTEGER [ ] ;
2012-05-07 03:18:31 +04:00
linked_node_id BIGINT ;
2017-05-31 00:36:59 +03:00
linked_importance FLOAT ;
linked_wikipedia TEXT ;
2012-04-30 04:05:06 +04:00
2010-10-24 03:12:37 +04:00
result BOOLEAN ;
BEGIN
2012-09-03 17:52:49 +04:00
-- deferred delete
IF OLD . indexed_status = 100 THEN
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' placex_update delete % % ' , NEW . osm_type , NEW . osm_id ;
2012-09-03 17:52:49 +04:00
delete from placex where place_id = OLD . place_id ;
RETURN NULL ;
END IF ;
2013-01-24 16:58:16 +04:00
IF NEW . indexed_status ! = 0 OR OLD . indexed_status = 0 THEN
2012-05-22 18:27:42 +04:00
RETURN NEW ;
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' placex_update % % (%) ' , NEW . osm_type , NEW . osm_id , NEW . place_id ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
NEW . indexed_date = now ( ) ;
2010-10-24 03:12:37 +04:00
2018-11-20 23:03:56 +03:00
IF NOT % REVERSE - ONLY % THEN
DELETE from search_name WHERE place_id = NEW . place_id ;
END IF ;
2016-04-25 10:44:01 +03:00
result : = deleteSearchName ( NEW . partition , NEW . place_id ) ;
DELETE FROM place_addressline WHERE place_id = NEW . place_id ;
result : = deleteRoad ( NEW . partition , NEW . place_id ) ;
result : = deleteLocationArea ( NEW . partition , NEW . place_id , NEW . rank_search ) ;
UPDATE placex set linked_place_id = null , indexed_status = 2
where linked_place_id = NEW . place_id ;
-- update not necessary for osmline, cause linked_place_id does not exist
2013-01-24 16:58:16 +04:00
2016-04-25 10:44:01 +03:00
IF NEW . linked_place_id is not null THEN
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' place already linked to % ' , NEW . linked_place_id ;
2016-04-25 10:44:01 +03:00
RETURN NEW ;
END IF ;
2010-10-24 03:12:37 +04:00
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Copy over address tags ' ;
2019-07-03 21:56:35 +03:00
-- housenumber is a computed field, so start with an empty value
NEW . housenumber : = NULL ;
2017-03-26 22:19:52 +03:00
IF NEW . address is not NULL THEN
IF NEW . address ? ' conscriptionnumber ' THEN
i : = getorcreate_housenumber_id ( make_standard_name ( NEW . address - > ' conscriptionnumber ' ) ) ;
IF NEW . address ? ' streetnumber ' THEN
i : = getorcreate_housenumber_id ( make_standard_name ( NEW . address - > ' streetnumber ' ) ) ;
2017-04-09 11:06:31 +03:00
NEW . housenumber : = ( NEW . address - > ' conscriptionnumber ' ) | | ' / ' | | ( NEW . address - > ' streetnumber ' ) ;
2017-03-26 22:19:52 +03:00
ELSE
NEW . housenumber : = NEW . address - > ' conscriptionnumber ' ;
END IF ;
ELSEIF NEW . address ? ' streetnumber ' THEN
NEW . housenumber : = NEW . address - > ' streetnumber ' ;
2017-03-26 01:11:09 +03:00
i : = getorcreate_housenumber_id ( make_standard_name ( NEW . address - > ' streetnumber ' ) ) ;
2017-03-26 22:19:52 +03:00
ELSEIF NEW . address ? ' housenumber ' THEN
NEW . housenumber : = NEW . address - > ' housenumber ' ;
i : = getorcreate_housenumber_id ( make_standard_name ( NEW . housenumber ) ) ;
END IF ;
2017-03-26 01:11:09 +03:00
2018-04-06 00:31:40 +03:00
addr_street : = NEW . address - > ' street ' ;
addr_place : = NEW . address - > ' place ' ;
2017-04-05 23:19:42 +03:00
2017-07-03 23:13:01 +03:00
IF NEW . address ? ' postcode ' and NEW . address - > ' postcode ' not similar to ' %(,|;)% ' THEN
i : = getorcreate_postcode_id ( NEW . address - > ' postcode ' ) ;
END IF ;
2017-03-26 01:11:09 +03:00
END IF ;
2016-04-25 10:44:01 +03:00
-- Speed up searches - just use the centroid of the feature
-- cheaper but less acurate
place_centroid : = ST_PointOnSurface ( NEW . geometry ) ;
2019-06-10 19:23:12 +03:00
-- For searching near features rather use the centroid
2019-07-28 14:28:27 +03:00
near_centroid : = ST_Envelope ( NEW . geometry ) ;
2016-04-25 10:44:01 +03:00
NEW . centroid : = null ;
2017-07-02 17:28:02 +03:00
NEW . postcode : = null ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Computing preliminary centroid at % ' , ST_AsText ( place_centroid ) ;
2016-04-25 10:44:01 +03:00
-- recalculate country and partition
2017-03-26 22:19:52 +03:00
IF NEW . rank_search = 4 AND NEW . address is not NULL AND NEW . address ? ' country ' THEN
2016-04-25 10:44:01 +03:00
-- for countries, believe the mapped country code,
-- so that we remain in the right partition if the boundaries
-- suddenly expand.
2017-03-26 01:11:09 +03:00
NEW . country_code : = lower ( NEW . address - > ' country ' ) ;
2016-04-25 10:44:01 +03:00
NEW . partition : = get_partition ( lower ( NEW . country_code ) ) ;
IF NEW . partition = 0 THEN
2017-03-26 01:11:09 +03:00
NEW . country_code : = lower ( get_country_code ( place_centroid ) ) ;
NEW . partition : = get_partition ( NEW . country_code ) ;
2012-04-16 01:05:31 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
ELSE
2017-03-26 01:11:09 +03:00
IF NEW . rank_search > = 4 THEN
NEW . country_code : = lower ( get_country_code ( place_centroid ) ) ;
2016-04-25 10:44:01 +03:00
ELSE
2017-03-26 01:11:09 +03:00
NEW . country_code : = NULL ;
2015-02-17 02:00:36 +03:00
END IF ;
2017-03-26 01:11:09 +03:00
NEW . partition : = get_partition ( NEW . country_code ) ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Country updated: "%" ' , NEW . country_code ;
2015-02-17 02:00:36 +03:00
2016-04-25 10:44:01 +03:00
-- waterway ways are linked when they are part of a relation and have the same class/type
IF NEW . osm_type = ' R ' and NEW . class = ' waterway ' THEN
FOR relation_members IN select members from planet_osm_rels r where r . id = NEW . osm_id and r . parts ! = array [ ] : : bigint [ ]
LOOP
FOR i IN 1 . . array_upper ( relation_members , 1 ) BY 2 LOOP
IF relation_members [ i + 1 ] in ( ' ' , ' main_stream ' , ' side_stream ' ) AND substring ( relation_members [ i ] , 1 , 1 ) = ' w ' THEN
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' waterway parent %, child %/% ' , NEW . osm_id , i , relation_members [ i ] ;
2016-04-25 10:44:01 +03:00
FOR linked_node_id IN SELECT place_id FROM placex
WHERE osm_type = ' W ' and osm_id = substring ( relation_members [ i ] , 2 , 200 ) : : bigint
2017-12-16 18:59:48 +03:00
and class = NEW . class and type in ( ' river ' , ' stream ' , ' canal ' , ' drain ' , ' ditch ' )
2016-04-25 10:44:01 +03:00
and ( relation_members [ i + 1 ] ! = ' side_stream ' or NEW . name - > ' name ' = name - > ' name ' )
LOOP
UPDATE placex SET linked_place_id = NEW . place_id WHERE place_id = linked_node_id ;
END LOOP ;
END IF ;
END LOOP ;
END LOOP ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Waterway processed ' ;
2016-04-25 10:44:01 +03:00
END IF ;
2014-05-08 00:46:23 +04:00
2016-04-25 10:44:01 +03:00
-- What level are we searching from
search_maxrank : = NEW . rank_search ;
-- Thought this wasn't needed but when we add new languages to the country_name table
-- we need to update the existing names
IF NEW . name is not null AND array_upper ( akeys ( NEW . name ) , 1 ) > 1 THEN
2017-03-26 01:11:09 +03:00
default_language : = get_country_language_code ( NEW . country_code ) ;
2016-04-25 10:44:01 +03:00
IF default_language IS NOT NULL THEN
IF NEW . name ? ' name ' AND NOT NEW . name ? ( ' name: ' | | default_language ) THEN
NEW . name : = NEW . name | | hstore ( ( ' name: ' | | default_language ) , ( NEW . name - > ' name ' ) ) ;
ELSEIF NEW . name ? ( ' name: ' | | default_language ) AND NOT NEW . name ? ' name ' THEN
NEW . name : = NEW . name | | hstore ( ' name ' , ( NEW . name - > ( ' name: ' | | default_language ) ) ) ;
2012-03-22 04:33:28 +04:00
END IF ;
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Local names updated ' ;
2012-03-22 04:33:28 +04:00
2016-04-25 10:44:01 +03:00
-- Initialise the name vector using our name
name_vector : = make_keywords ( NEW . name ) ;
nameaddress_vector : = ' {} ' : : int [ ] ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
FOR i IN 1 . . 28 LOOP
address_havelevel [ i ] : = false ;
END LOOP ;
2010-11-09 13:19:36 +03:00
2016-04-25 10:44:01 +03:00
NEW . importance : = null ;
2019-11-17 12:06:34 +03:00
SELECT wikipedia , importance
2019-10-28 00:18:05 +03:00
FROM compute_importance ( NEW . extratags , NEW . country_code , NEW . osm_type , NEW . osm_id )
INTO NEW . wikipedia , NEW . importance ;
2012-04-30 04:05:06 +04:00
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Importance computed from wikipedia: % ' , NEW . importance ;
2010-10-24 03:12:37 +04:00
2016-05-28 19:18:18 +03:00
-- ---------------------------------------------------------------------------
2016-04-25 10:44:01 +03:00
-- For low level elements we inherit from our parent road
IF ( NEW . rank_search > 27 OR ( NEW . type = ' postcode ' AND NEW . rank_search = 25 ) ) THEN
2010-10-24 03:12:37 +04:00
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' finding street for % % ' , NEW . osm_type , NEW . osm_id ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- We won't get a better centroid, besides these places are too small to care
NEW . centroid : = place_centroid ;
NEW . parent_place_id : = null ;
-- if we have a POI and there is no address information,
-- see if we can get it from a surrounding building
2017-04-05 23:19:42 +03:00
IF NEW . osm_type = ' N ' AND addr_street IS NULL AND addr_place IS NULL
2016-04-25 10:44:01 +03:00
AND NEW . housenumber IS NULL THEN
2018-04-06 00:31:40 +03:00
FOR location IN select address from placex where ST_Covers ( geometry , place_centroid )
2017-04-02 16:19:39 +03:00
and address is not null
and ( address ? ' housenumber ' or address ? ' street ' or address ? ' place ' )
2016-04-25 10:44:01 +03:00
and rank_search > 28 AND ST_GeometryType ( geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' )
limit 1
LOOP
2017-04-02 16:19:39 +03:00
NEW . housenumber : = location . address - > ' housenumber ' ;
2017-04-05 23:19:42 +03:00
addr_street : = location . address - > ' street ' ;
addr_place : = location . address - > ' place ' ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Found surrounding building % % ' , location . osm_type , location . osm_id ;
2016-04-25 10:44:01 +03:00
END LOOP ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- We have to find our parent road.
-- Copy data from linked items (points on ways, addr:street links, relations)
2014-04-30 22:05:59 +04:00
2016-04-25 10:44:01 +03:00
-- Is this object part of a relation?
FOR relation IN select * from planet_osm_rels where parts @ > ARRAY [ NEW . osm_id ] and members @ > ARRAY [ lower ( NEW . osm_type ) | | NEW . osm_id ]
LOOP
-- At the moment we only process one type of relation - associatedStreet
IF relation . tags @ > ARRAY [ ' associatedStreet ' ] THEN
FOR i IN 1 . . array_upper ( relation . members , 1 ) BY 2 LOOP
IF NEW . parent_place_id IS NULL AND relation . members [ i + 1 ] = ' street ' THEN
2010-10-24 03:12:37 +04:00
- - RAISE WARNING ' node in relation % ' , relation ;
2016-04-25 10:44:01 +03:00
SELECT place_id from placex where osm_type = ' W '
and osm_id = substring ( relation . members [ i ] , 2 , 200 ) : : bigint
and rank_search = 26 and name is not null INTO NEW . parent_place_id ;
2010-10-24 03:12:37 +04:00
END IF ;
2015-02-26 01:04:24 +03:00
END LOOP ;
2016-04-25 10:44:01 +03:00
END IF ;
END LOOP ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for street relation (%) ' , NEW . parent_place_id ;
2015-02-26 01:04:24 +03:00
2016-04-25 10:44:01 +03:00
-- Note that addr:street links can only be indexed once the street itself is indexed
2017-04-05 23:19:42 +03:00
IF NEW . parent_place_id IS NULL AND addr_street IS NOT NULL THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( addr_street ) ) ;
2016-04-25 10:44:01 +03:00
IF address_street_word_ids IS NOT NULL THEN
2019-06-10 19:23:12 +03:00
SELECT place_id from getNearestNamedRoadFeature ( NEW . partition , near_centroid , address_street_word_ids ) INTO NEW . parent_place_id ;
2015-02-26 01:04:24 +03:00
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for addr:street (%) ' , NEW . parent_place_id ;
2015-02-26 01:04:24 +03:00
2017-04-05 23:19:42 +03:00
IF NEW . parent_place_id IS NULL AND addr_place IS NOT NULL THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( addr_place ) ) ;
2016-04-25 10:44:01 +03:00
IF address_street_word_ids IS NOT NULL THEN
2019-06-10 19:23:12 +03:00
SELECT place_id from getNearestNamedPlaceFeature ( NEW . partition , near_centroid , address_street_word_ids ) INTO NEW . parent_place_id ;
2015-02-26 01:04:24 +03:00
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for addr:place (%) ' , NEW . parent_place_id ;
2015-02-26 01:04:24 +03:00
2016-05-28 19:18:18 +03:00
-- Is this node part of an interpolation?
2016-04-25 10:44:01 +03:00
IF NEW . parent_place_id IS NULL AND NEW . osm_type = ' N ' THEN
2018-04-06 00:31:40 +03:00
SELECT q . parent_place_id FROM location_property_osmline q , planet_osm_ways x
WHERE q . linegeo & & NEW . geometry and x . id = q . osm_id and NEW . osm_id = any ( x . nodes )
LIMIT 1 INTO NEW . parent_place_id ;
2016-05-28 19:18:18 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for interpolation (%) ' , NEW . parent_place_id ;
2010-10-24 03:12:37 +04:00
2016-05-28 19:18:18 +03:00
-- Is this node part of a way?
IF NEW . parent_place_id IS NULL AND NEW . osm_type = ' N ' THEN
2018-04-06 00:31:40 +03:00
FOR location IN
SELECT p . place_id , p . osm_id , p . rank_search , p . address from placex p , planet_osm_ways w
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 )
2016-04-25 10:44:01 +03:00
LOOP
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Node is part of way % ' , location . osm_id ;
2016-05-28 19:18:18 +03:00
2016-04-25 10:44:01 +03:00
-- Way IS a road then we are on it - that must be our road
2018-04-06 00:31:40 +03:00
IF location . rank_search < 28 THEN
2010-10-24 03:12:37 +04:00
- - RAISE WARNING ' node in way that is a street % ' , location ;
2016-04-25 10:44:01 +03:00
NEW . parent_place_id : = location . place_id ;
2018-04-06 00:31:40 +03:00
EXIT ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked if way is street (%) ' , NEW . parent_place_id ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- If the way mentions a street or place address, try that for parenting.
2018-04-06 00:31:40 +03:00
IF location . address is not null THEN
IF location . address ? ' street ' THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( location . address - > ' street ' ) ) ;
IF address_street_word_ids IS NOT NULL THEN
2019-06-10 19:23:12 +03:00
SELECT place_id from getNearestNamedRoadFeature ( NEW . partition , near_centroid , address_street_word_ids ) INTO NEW . parent_place_id ;
2018-04-06 00:31:40 +03:00
EXIT WHEN NEW . parent_place_id is not NULL ;
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
2018-04-06 00:31:40 +03:00
- - DEBUG : RAISE WARNING ' Checked for addr:street in way (%) ' , NEW . parent_place_id ;
2010-10-24 03:12:37 +04:00
2018-04-06 00:31:40 +03:00
IF location . address ? ' place ' THEN
address_street_word_ids : = get_name_ids ( make_standard_name ( location . address - > ' place ' ) ) ;
IF address_street_word_ids IS NOT NULL THEN
2019-06-10 19:23:12 +03:00
SELECT place_id from getNearestNamedPlaceFeature ( NEW . partition , near_centroid , address_street_word_ids ) INTO NEW . parent_place_id ;
2018-04-06 00:31:40 +03:00
EXIT WHEN NEW . parent_place_id is not NULL ;
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for addr:place in way (%) ' , NEW . parent_place_id ;
2018-04-06 00:31:40 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2016-05-28 19:18:18 +03:00
-- Is the WAY part of a relation
2018-04-06 00:31:40 +03:00
FOR relation IN select * from planet_osm_rels where parts @ > ARRAY [ location . osm_id ] and members @ > ARRAY [ ' w ' | | location . osm_id ]
LOOP
-- At the moment we only process one type of relation - associatedStreet
IF relation . tags @ > ARRAY [ ' associatedStreet ' ] AND array_upper ( relation . members , 1 ) IS NOT NULL THEN
FOR i IN 1 . . array_upper ( relation . members , 1 ) BY 2 LOOP
IF NEW . parent_place_id IS NULL AND relation . members [ i + 1 ] = ' street ' THEN
- - RAISE WARNING ' node in way that is in a relation % ' , relation ;
SELECT place_id from placex where osm_type = ' W ' and osm_id = substring ( relation . members [ i ] , 2 , 200 ) : : bigint
and rank_search = 26 and name is not null INTO NEW . parent_place_id ;
2016-05-28 19:18:18 +03:00
END IF ;
END LOOP ;
2018-04-06 00:31:40 +03:00
END IF ;
END LOOP ;
EXIT WHEN NEW . parent_place_id is not null ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for street relation in way (%) ' , NEW . parent_place_id ;
2016-05-28 19:18:18 +03:00
2016-04-25 10:44:01 +03:00
END LOOP ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Still nothing, just use the nearest road
IF NEW . parent_place_id IS NULL THEN
2019-06-10 19:23:12 +03:00
SELECT place_id FROM getNearestRoadFeature ( NEW . partition , near_centroid ) INTO NEW . parent_place_id ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Checked for nearest way (%) ' , NEW . parent_place_id ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- If we didn't find any road fallback to standard method
IF NEW . parent_place_id IS NOT NULL THEN
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Get the details of the parent road
2018-11-20 23:03:56 +03:00
SELECT p . country_code , p . postcode FROM placex p
WHERE p . place_id = NEW . parent_place_id INTO location ;
2017-03-26 01:11:09 +03:00
NEW . country_code : = location . country_code ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Got parent details from search name ' ;
2010-10-24 03:12:37 +04:00
2017-07-01 23:49:24 +03:00
-- determine postcode
2017-07-09 18:29:48 +03:00
IF NEW . rank_search > 4 THEN
IF NEW . address is not null AND NEW . address ? ' postcode ' THEN
2017-07-16 20:55:55 +03:00
NEW . postcode = upper ( trim ( NEW . address - > ' postcode ' ) ) ;
2017-07-09 18:29:48 +03:00
ELSE
2018-11-20 23:03:56 +03:00
NEW . postcode : = location . postcode ;
2017-07-09 18:29:48 +03:00
END IF ;
IF NEW . postcode is null THEN
2019-07-28 14:28:27 +03:00
NEW . postcode : = get_nearest_postcode ( NEW . country_code , NEW . geometry ) ;
2017-07-09 18:29:48 +03:00
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- If there is no name it isn't searchable, don't bother to create a search record
IF NEW . name is NULL THEN
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Not a searchable place % % ' , NEW . osm_type , NEW . osm_id ;
2016-04-25 10:44:01 +03:00
return NEW ;
END IF ;
2010-12-07 16:41:02 +03:00
2016-04-25 10:44:01 +03:00
-- Performance, it would be more acurate to do all the rest of the import
-- process but it takes too long
-- Just be happy with inheriting from parent road only
IF NEW . rank_search < = 25 and NEW . rank_address > 0 THEN
2017-07-16 20:55:55 +03:00
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 ) ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Place added to location table ' ;
2010-10-24 03:12:37 +04:00
END IF ;
2018-11-20 23:03:56 +03:00
result : = insertSearchName ( NEW . partition , NEW . place_id , name_vector ,
NEW . rank_search , NEW . rank_address , NEW . geometry ) ;
IF NOT % REVERSE - ONLY % THEN
-- Merge address from parent
SELECT s . name_vector , s . nameaddress_vector FROM search_name s
WHERE s . place_id = NEW . parent_place_id INTO location ;
nameaddress_vector : = array_merge ( nameaddress_vector ,
location . nameaddress_vector ) ;
nameaddress_vector : = array_merge ( nameaddress_vector , location . name_vector ) ;
INSERT INTO search_name ( place_id , search_rank , address_rank ,
importance , country_code , name_vector ,
nameaddress_vector , centroid )
VALUES ( NEW . place_id , NEW . rank_search , NEW . rank_address ,
NEW . importance , NEW . country_code , name_vector ,
nameaddress_vector , place_centroid ) ;
- - DEBUG : RAISE WARNING ' Place added to search table ' ;
END IF ;
2016-04-25 10:44:01 +03:00
return NEW ;
2010-10-24 03:12:37 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2016-05-28 19:18:18 +03:00
-- ---------------------------------------------------------------------------
-- Full indexing
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Using full index mode for % % ' , NEW . osm_type , NEW . osm_id ;
2016-05-28 19:18:18 +03:00
2016-04-25 10:44:01 +03:00
IF NEW . osm_type = ' R ' AND NEW . rank_search < 26 THEN
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- see if we have any special relation members
select members from planet_osm_rels where id = NEW . osm_id INTO relation_members ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Got relation members ' ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
IF relation_members IS NOT NULL THEN
FOR relMember IN select get_osm_rel_members ( relation_members , ARRAY [ ' label ' ] ) as member LOOP
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Found label member % ' , relMember . member ;
2012-04-01 04:40:50 +04:00
2017-06-04 18:57:08 +03:00
FOR linkedPlacex IN select * from placex where osm_type = upper ( substring ( relMember . member , 1 , 1 ) ) : : char ( 1 )
2017-06-07 22:32:02 +03:00
and osm_id = substring ( relMember . member , 2 , 10000 ) : : bigint
and class = ' place ' order by rank_search desc limit 1 LOOP
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- If we don't already have one use this as the centre point of the geometry
IF NEW . centroid IS NULL THEN
NEW . centroid : = coalesce ( linkedPlacex . centroid , st_centroid ( linkedPlacex . geometry ) ) ;
END IF ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- merge in the label name, re-init word vector
IF NOT linkedPlacex . name IS NULL THEN
NEW . name : = linkedPlacex . name | | NEW . name ;
name_vector : = array_merge ( name_vector , make_keywords ( linkedPlacex . name ) ) ;
END IF ;
2013-02-28 16:47:13 +04:00
2016-04-25 10:44:01 +03:00
-- merge in extra tags
NEW . extratags : = hstore ( linkedPlacex . class , linkedPlacex . type ) | | coalesce ( linkedPlacex . extratags , ' ' : : hstore ) | | coalesce ( NEW . extratags , ' ' : : hstore ) ;
2012-09-29 00:58:29 +04:00
2016-04-25 10:44:01 +03:00
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW . place_id where place_id = linkedPlacex . place_id ;
2012-09-23 20:06:41 +04:00
2019-10-28 00:18:05 +03:00
select wikipedia , importance
FROM compute_importance ( linkedPlacex . extratags , NEW . country_code ,
' N ' , linkedPlacex . osm_id )
INTO linked_wikipedia , linked_importance ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Linked label member ' ;
2012-09-23 20:06:41 +04:00
END LOOP ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
END LOOP ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
IF NEW . centroid IS NULL THEN
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
FOR relMember IN select get_osm_rel_members ( relation_members , ARRAY [ ' admin_center ' , ' admin_centre ' ] ) as member LOOP
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Found admin_center member % ' , relMember . member ;
2012-04-01 04:40:50 +04:00
2017-06-04 18:57:08 +03:00
FOR linkedPlacex IN select * from placex where osm_type = upper ( substring ( relMember . member , 1 , 1 ) ) : : char ( 1 )
2017-06-07 22:32:02 +03:00
and osm_id = substring ( relMember . member , 2 , 10000 ) : : bigint
and class = ' place ' order by rank_search desc limit 1 LOOP
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- For an admin centre we also want a name match - still not perfect, for example 'new york, new york'
-- But that can be fixed by explicitly setting the label in the data
IF make_standard_name ( NEW . name - > ' name ' ) = make_standard_name ( linkedPlacex . name - > ' name ' )
AND NEW . rank_address = linkedPlacex . rank_address THEN
2012-05-11 21:23:44 +04:00
2016-04-25 10:44:01 +03:00
-- If we don't already have one use this as the centre point of the geometry
IF NEW . centroid IS NULL THEN
NEW . centroid : = coalesce ( linkedPlacex . centroid , st_centroid ( linkedPlacex . geometry ) ) ;
END IF ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- merge in the name, re-init word vector
IF NOT linkedPlacex . name IS NULL THEN
NEW . name : = linkedPlacex . name | | NEW . name ;
name_vector : = make_keywords ( NEW . name ) ;
END IF ;
2013-02-28 16:47:13 +04:00
2016-04-25 10:44:01 +03:00
-- merge in extra tags
NEW . extratags : = hstore ( linkedPlacex . class , linkedPlacex . type ) | | coalesce ( linkedPlacex . extratags , ' ' : : hstore ) | | coalesce ( NEW . extratags , ' ' : : hstore ) ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW . place_id where place_id = linkedPlacex . place_id ;
2012-05-07 03:18:31 +04:00
2019-10-28 00:18:05 +03:00
select wikipedia , importance
FROM compute_importance ( linkedPlacex . extratags , NEW . country_code ,
' N ' , linkedPlacex . osm_id )
INTO linked_wikipedia , linked_importance ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Linked admin_center ' ;
2016-04-25 10:44:01 +03:00
END IF ;
2012-09-23 20:06:41 +04:00
END LOOP ;
2012-04-02 15:48:51 +04:00
2016-04-25 10:44:01 +03:00
END LOOP ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
END IF ;
2013-06-18 16:09:30 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2013-06-18 16:09:30 +04:00
2016-04-25 10:44:01 +03:00
-- Name searches can be done for ways as well as relations
IF NEW . osm_type in ( ' W ' , ' R ' ) AND NEW . rank_search < 26 AND NEW . rank_address > 0 THEN
2012-04-29 19:40:44 +04:00
2016-04-25 10:44:01 +03:00
-- not found one yet? how about doing a name search
IF NEW . centroid IS NULL AND ( NEW . name - > ' name ' ) is not null and make_standard_name ( NEW . name - > ' name ' ) ! = ' ' THEN
2012-04-26 16:01:26 +04:00
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Looking for nodes with matching names ' ;
2016-04-25 10:44:01 +03:00
FOR linkedPlacex IN select placex . * from placex WHERE
make_standard_name ( name - > ' name ' ) = make_standard_name ( NEW . name - > ' name ' )
AND placex . rank_address = NEW . rank_address
AND placex . place_id ! = NEW . place_id
2017-06-04 18:57:08 +03:00
AND placex . osm_type = ' N ' : : char ( 1 ) AND placex . rank_search < 26
2016-04-25 10:44:01 +03:00
AND st_covers ( NEW . geometry , placex . geometry )
LOOP
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Found matching place node % ' , linkedPlacex . osm_id ;
2016-04-25 10:44:01 +03:00
-- If we don't already have one use this as the centre point of the geometry
IF NEW . centroid IS NULL THEN
NEW . centroid : = coalesce ( linkedPlacex . centroid , st_centroid ( linkedPlacex . geometry ) ) ;
END IF ;
2012-04-01 04:40:50 +04:00
2016-04-25 10:44:01 +03:00
-- merge in the name, re-init word vector
NEW . name : = linkedPlacex . name | | NEW . name ;
name_vector : = make_keywords ( NEW . name ) ;
2013-02-28 16:47:13 +04:00
2016-04-25 10:44:01 +03:00
-- merge in extra tags
NEW . extratags : = hstore ( linkedPlacex . class , linkedPlacex . type ) | | coalesce ( linkedPlacex . extratags , ' ' : : hstore ) | | coalesce ( NEW . extratags , ' ' : : hstore ) ;
2012-04-01 05:38:40 +04:00
2016-04-25 10:44:01 +03:00
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW . place_id where place_id = linkedPlacex . place_id ;
2012-04-01 04:40:50 +04:00
2019-10-28 00:18:05 +03:00
select wikipedia , importance
FROM compute_importance ( linkedPlacex . extratags , NEW . country_code ,
' N ' , linkedPlacex . osm_id )
INTO linked_wikipedia , linked_importance ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Linked named place ' ;
2016-04-25 10:44:01 +03:00
END LOOP ;
END IF ;
IF NEW . centroid IS NOT NULL THEN
place_centroid : = NEW . centroid ;
-- Place might have had only a name tag before but has now received translations
-- from the linked place. Make sure a name tag for the default language exists in
-- this case.
IF NEW . name is not null AND array_upper ( akeys ( NEW . name ) , 1 ) > 1 THEN
2017-03-26 01:11:09 +03:00
default_language : = get_country_language_code ( NEW . country_code ) ;
2016-04-25 10:44:01 +03:00
IF default_language IS NOT NULL THEN
IF NEW . name ? ' name ' AND NOT NEW . name ? ( ' name: ' | | default_language ) THEN
NEW . name : = NEW . name | | hstore ( ( ' name: ' | | default_language ) , ( NEW . name - > ' name ' ) ) ;
ELSEIF NEW . name ? ( ' name: ' | | default_language ) AND NOT NEW . name ? ' name ' THEN
NEW . name : = NEW . name | | hstore ( ' name ' , ( NEW . name - > ( ' name: ' | | default_language ) ) ) ;
2013-02-27 01:29:16 +04:00
END IF ;
END IF ;
2012-04-01 04:40:50 +04:00
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Names updated from linked places ' ;
2012-04-01 04:40:50 +04:00
END IF ;
2017-05-31 00:36:59 +03:00
-- Use the maximum importance if a one could be computed from the linked object.
IF linked_importance is not null AND
( NEW . importance is null or NEW . importance < linked_importance ) THEN
NEW . importance = linked_importance ;
2016-04-25 10:44:01 +03:00
END IF ;
END IF ;
2013-02-07 22:38:48 +04:00
2016-04-25 10:44:01 +03:00
-- make sure all names are in the word table
2017-10-12 22:03:03 +03:00
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
2016-04-25 10:44:01 +03:00
perform create_country ( NEW . name , lower ( NEW . country_code ) ) ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Country names updated ' ;
2016-04-25 10:44:01 +03:00
END IF ;
2013-02-07 22:38:48 +04:00
2016-04-25 10:44:01 +03:00
NEW . parent_place_id = 0 ;
parent_place_id_rank = 0 ;
2016-04-25 12:01:04 +03:00
2018-04-15 23:00:56 +03:00
-- convert address store to array of tokenids
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Starting address search ' ;
2016-04-25 10:44:01 +03:00
isin_tokens : = ' {} ' : : int [ ] ;
2017-03-26 01:11:09 +03:00
IF NEW . address IS NOT NULL THEN
2018-04-15 23:00:56 +03:00
FOR addr_item IN SELECT * FROM each ( NEW . address )
LOOP
IF addr_item . key IN ( ' city ' , ' tiger:county ' , ' state ' , ' suburb ' , ' province ' , ' district ' , ' region ' , ' county ' , ' municipality ' , ' hamlet ' , ' village ' , ' subdistrict ' , ' town ' , ' neighbourhood ' , ' quarter ' , ' parish ' ) THEN
address_street_word_id : = get_name_id ( make_standard_name ( addr_item . value ) ) ;
2016-04-25 10:44:01 +03:00
IF address_street_word_id IS NOT NULL AND NOT ( ARRAY [ address_street_word_id ] < @ isin_tokens ) THEN
isin_tokens : = isin_tokens | | address_street_word_id ;
END IF ;
2018-11-20 23:03:56 +03:00
IF NOT % REVERSE - ONLY % THEN
address_street_word_id : = get_word_id ( make_standard_name ( addr_item . value ) ) ;
IF address_street_word_id IS NOT NULL THEN
nameaddress_vector : = array_merge ( nameaddress_vector , ARRAY [ address_street_word_id ] ) ;
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
2018-04-15 23:00:56 +03:00
END IF ;
IF addr_item . key = ' is_in ' THEN
-- is_in items need splitting
2018-04-16 21:16:11 +03:00
isin : = regexp_split_to_array ( addr_item . value , E ' [;,] ' ) ;
2018-04-15 23:00:56 +03:00
IF array_upper ( isin , 1 ) IS NOT NULL THEN
FOR i IN 1 . . array_upper ( isin , 1 ) LOOP
address_street_word_id : = get_name_id ( make_standard_name ( isin [ i ] ) ) ;
IF address_street_word_id IS NOT NULL AND NOT ( ARRAY [ address_street_word_id ] < @ isin_tokens ) THEN
isin_tokens : = isin_tokens | | address_street_word_id ;
END IF ;
-- merge word into address vector
2018-11-20 23:03:56 +03:00
IF NOT % REVERSE - ONLY % THEN
address_street_word_id : = get_word_id ( make_standard_name ( isin [ i ] ) ) ;
IF address_street_word_id IS NOT NULL THEN
nameaddress_vector : = array_merge ( nameaddress_vector , ARRAY [ address_street_word_id ] ) ;
END IF ;
2018-04-15 23:00:56 +03:00
END IF ;
END LOOP ;
END IF ;
END IF ;
END LOOP ;
2016-04-25 10:44:01 +03:00
END IF ;
2018-11-20 23:03:56 +03:00
IF NOT % REVERSE - ONLY % THEN
nameaddress_vector : = array_merge ( nameaddress_vector , isin_tokens ) ;
END IF ;
2016-04-25 10:44:01 +03:00
2012-05-22 18:27:42 +04:00
-- RAISE WARNING 'ISIN: %', isin_tokens;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Process area matches
location_rank_search : = 0 ;
location_distance : = 0 ;
location_parent : = NULL ;
-- added ourself as address already
address_havelevel [ NEW . rank_address ] : = true ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' getNearFeatures(%, '' % '' ,%, '' % '' ) ' , NEW . partition , place_centroid , search_maxrank , isin_tokens ;
2017-03-18 14:17:48 +03:00
FOR location IN
SELECT * from getNearFeatures ( NEW . partition ,
2017-04-10 00:12:35 +03:00
CASE WHEN NEW . rank_search > = 26
AND NEW . rank_search < 30
THEN NEW . geometry
2019-07-28 14:28:27 +03:00
ELSE place_centroid END ,
2017-03-18 14:17:48 +03:00
search_maxrank , isin_tokens )
LOOP
2016-04-25 10:44:01 +03:00
IF location . rank_address ! = location_rank_search THEN
location_rank_search : = location . rank_address ;
IF location . isguess THEN
location_distance : = location . distance * 1 . 5 ;
ELSE
IF location . rank_address < = 12 THEN
-- for county and above, if we have an area consider that exact
-- (It would be nice to relax the constraint for places close to
-- the boundary but we'd need the exact geometry for that. Too
-- expensive.)
location_distance = 0 ;
2015-02-07 01:22:20 +03:00
ELSE
2016-04-25 10:44:01 +03:00
-- Below county level remain slightly fuzzy.
location_distance : = location . distance * 0 . 5 ;
2015-02-07 01:22:20 +03:00
END IF ;
2010-10-26 19:22:41 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
ELSE
CONTINUE WHEN location . keywords < @ location_keywords ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
IF location . distance < location_distance OR NOT location . isguess THEN
location_keywords : = location . keywords ;
2012-07-04 00:44:06 +04:00
2016-04-25 10:44:01 +03:00
location_isaddress : = NOT address_havelevel [ location . rank_address ] ;
IF location_isaddress AND location . isguess AND location_parent IS NOT NULL THEN
location_isaddress : = ST_Contains ( location_parent , location . centroid ) ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
-- Add it to the list of search terms
2019-07-09 21:47:25 +03:00
IF NOT % REVERSE - ONLY % THEN
2016-04-25 10:44:01 +03:00
nameaddress_vector : = array_merge ( nameaddress_vector , location . keywords : : integer [ ] ) ;
END IF ;
2017-04-14 16:50:27 +03:00
INSERT INTO place_addressline ( place_id , address_place_id , fromarea , isaddress , distance , cached_rank_address )
VALUES ( NEW . place_id , location . place_id , true , location_isaddress , location . distance , location . rank_address ) ;
2013-09-09 17:06:57 +04:00
2016-04-25 10:44:01 +03:00
IF location_isaddress THEN
2017-07-01 23:49:24 +03:00
-- add postcode if we have one
-- (If multiple postcodes are available, we end up with the highest ranking one.)
IF location . postcode is not null THEN
NEW . postcode = location . postcode ;
END IF ;
2011-06-14 17:42:46 +04:00
2016-04-25 10:44:01 +03:00
address_havelevel [ location . rank_address ] : = true ;
IF NOT location . isguess THEN
SELECT geometry FROM placex WHERE place_id = location . place_id INTO location_parent ;
2010-12-07 16:41:02 +03:00
END IF ;
2016-04-25 10:44:01 +03:00
IF location . rank_address > parent_place_id_rank THEN
NEW . parent_place_id = location . place_id ;
parent_place_id_rank = location . rank_address ;
END IF ;
2013-09-09 17:06:57 +04:00
2010-10-26 19:22:41 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' Terms: (%) % ' , location , nameaddress_vector ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
END IF ;
2011-01-05 17:07:26 +03:00
2016-04-25 10:44:01 +03:00
END LOOP ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' address computed ' ;
2011-02-08 15:09:11 +03:00
2017-07-01 23:49:24 +03:00
IF NEW . address is not null AND NEW . address ? ' postcode '
AND NEW . address - > ' postcode ' not similar to ' %(,|;)% ' THEN
2017-07-16 20:55:55 +03:00
NEW . postcode : = upper ( trim ( NEW . address - > ' postcode ' ) ) ;
2017-07-01 23:49:24 +03:00
END IF ;
IF NEW . postcode is null AND NEW . rank_search > 8 THEN
NEW . postcode : = get_nearest_postcode ( NEW . country_code , NEW . geometry ) ;
END IF ;
2016-04-25 10:44:01 +03:00
-- if we have a name add this to the name search table
IF NEW . name IS NOT NULL THEN
2010-11-09 13:19:36 +03:00
2016-04-25 10:44:01 +03:00
IF NEW . rank_search < = 25 and NEW . rank_address > 0 THEN
2017-07-16 20:55:55 +03:00
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 ) ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' added to location (full) ' ;
2010-10-24 03:12:37 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
IF NEW . rank_search between 26 and 27 and NEW . class = ' highway ' THEN
2017-03-26 01:11:09 +03:00
result : = insertLocationRoad ( NEW . partition , NEW . place_id , NEW . country_code , NEW . geometry ) ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' insert into road location table (full) ' ;
2012-04-01 04:40:50 +04:00
END IF ;
2018-11-20 23:03:56 +03:00
result : = insertSearchName ( NEW . partition , NEW . place_id , name_vector ,
NEW . rank_search , NEW . rank_address , NEW . geometry ) ;
- - DEBUG : RAISE WARNING ' added to search name (full) ' ;
IF NOT % REVERSE - ONLY % THEN
INSERT INTO search_name ( place_id , search_rank , address_rank ,
importance , country_code , name_vector ,
nameaddress_vector , centroid )
VALUES ( NEW . place_id , NEW . rank_search , NEW . rank_address ,
NEW . importance , NEW . country_code , name_vector ,
nameaddress_vector , place_centroid ) ;
END IF ;
2016-04-25 10:44:01 +03:00
2010-10-24 03:12:37 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
-- If we've not managed to pick up a better one - default centroid
IF NEW . centroid IS NULL THEN
NEW . centroid : = place_centroid ;
END IF ;
2017-06-16 00:08:58 +03:00
- - DEBUG : RAISE WARNING ' place update % % finsihed. ' , NEW . osm_type , NEW . osm_id ;
2010-10-26 19:22:41 +04:00
RETURN NEW ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION placex_delete ( ) RETURNS TRIGGER
AS $ $
DECLARE
2010-11-09 13:19:36 +03:00
b BOOLEAN ;
2012-02-19 14:33:21 +04:00
classtable TEXT ;
2010-10-24 03:12:37 +04:00
BEGIN
2012-06-29 00:09:44 +04:00
-- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
2010-10-24 03:12:37 +04:00
2012-08-28 21:41:02 +04:00
update placex set linked_place_id = null , indexed_status = 2 where linked_place_id = OLD . place_id and indexed_status = 0 ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:01 % % ' , OLD . osm_type , OLD . osm_id ;
2012-08-28 21:41:02 +04:00
update placex set linked_place_id = null where linked_place_id = OLD . place_id ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:02 % % ' , OLD . osm_type , OLD . osm_id ;
2012-04-01 04:40:50 +04:00
2010-11-17 18:19:25 +03:00
IF OLD . rank_address < 30 THEN
-- mark everything linked to this place for re-indexing
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:03 % % ' , OLD . osm_type , OLD . osm_id ;
2010-11-17 18:19:25 +03:00
UPDATE placex set indexed_status = 2 from place_addressline where address_place_id = OLD . place_id
2014-02-08 02:37:54 +04:00
and placex . place_id = place_addressline . place_id and indexed_status = 0 and place_addressline . isaddress ;
2010-11-17 18:19:25 +03:00
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:04 % % ' , OLD . osm_type , OLD . osm_id ;
2010-11-17 18:19:25 +03:00
DELETE FROM place_addressline where address_place_id = OLD . place_id ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:05 % % ' , OLD . osm_type , OLD . osm_id ;
2011-02-07 14:13:18 +03:00
b : = deleteRoad ( OLD . partition , OLD . place_id ) ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:06 % % ' , OLD . osm_type , OLD . osm_id ;
2011-02-07 14:13:18 +03:00
update placex set indexed_status = 2 where parent_place_id = OLD . place_id and indexed_status = 0 ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:07 % % ' , OLD . osm_type , OLD . osm_id ;
2016-04-25 10:44:01 +03:00
-- reparenting also for OSM Interpolation Lines (and for Tiger?)
update location_property_osmline set indexed_status = 2 where indexed_status = 0 and parent_place_id = OLD . place_id ;
2011-02-07 14:13:18 +03:00
2010-11-17 18:19:25 +03:00
END IF ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:08 % % ' , OLD . osm_type , OLD . osm_id ;
2010-11-17 18:19:25 +03:00
IF OLD . rank_address < 26 THEN
2013-01-22 11:01:30 +04:00
b : = deleteLocationArea ( OLD . partition , OLD . place_id , OLD . rank_search ) ;
2010-11-17 18:19:25 +03:00
END IF ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:09 % % ' , OLD . osm_type , OLD . osm_id ;
2010-11-17 18:19:25 +03:00
IF OLD . name is not null THEN
2018-11-20 23:03:56 +03:00
IF NOT % REVERSE - ONLY % THEN
DELETE from search_name WHERE place_id = OLD . place_id ;
END IF ;
2010-11-17 18:19:25 +03:00
b : = deleteSearchName ( OLD . partition , OLD . place_id ) ;
END IF ;
2010-10-24 03:12:37 +04:00
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:10 % % ' , OLD . osm_type , OLD . osm_id ;
2010-10-24 03:12:37 +04:00
DELETE FROM place_addressline where place_id = OLD . place_id ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:11 % % ' , OLD . osm_type , OLD . osm_id ;
2012-02-19 14:33:21 +04:00
-- remove from tables for special search
classtable : = ' place_classtype_ ' | | OLD . class | | ' _ ' | | OLD . type ;
2013-11-23 16:31:29 +04:00
SELECT count ( * ) > 0 FROM pg_tables WHERE tablename = classtable and schemaname = current_schema ( ) INTO b ;
2012-02-19 14:33:21 +04:00
IF b THEN
EXECUTE ' DELETE FROM ' | | classtable : : regclass | | ' WHERE place_id = $1 ' USING OLD . place_id ;
END IF ;
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' placex_delete:12 % % ' , OLD . osm_type , OLD . osm_id ;
2010-10-24 03:12:37 +04:00
RETURN OLD ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION place_delete ( ) RETURNS TRIGGER
AS $ $
DECLARE
2014-04-12 00:28:07 +04:00
has_rank BOOLEAN ;
2010-10-24 03:12:37 +04:00
BEGIN
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' delete: % % % % ' , OLD . osm_type , OLD . osm_id , OLD . class , OLD . type ;
2011-01-05 17:07:26 +03:00
2012-06-30 00:11:40 +04:00
-- deleting large polygons can have a massive effect on the system - require manual intervention to let them through
IF st_area ( OLD . geometry ) > 2 and st_isvalid ( OLD . geometry ) THEN
2014-04-12 00:28:07 +04:00
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 ;
IF has_rank THEN
2017-04-14 16:50:27 +03:00
insert into import_polygon_delete ( osm_type , osm_id , class , type ) values ( OLD . osm_type , OLD . osm_id , OLD . class , OLD . type ) ;
2014-04-12 00:28:07 +04:00
RETURN NULL ;
END IF ;
2011-03-18 12:52:16 +03:00
END IF ;
2011-01-05 17:07:26 +03:00
-- mark for delete
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 ;
2015-02-24 01:29:31 +03:00
-- interpolations are special
2016-04-27 18:42:59 +03:00
IF OLD . osm_type = ' W ' and OLD . class = ' place ' and OLD . type = ' houses ' THEN
2016-04-25 10:44:01 +03:00
UPDATE location_property_osmline set indexed_status = 100 where osm_id = OLD . osm_id ; -- osm_id = wayid (=old.osm_id)
2015-02-24 01:29:31 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
RETURN OLD ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION place_insert ( ) RETURNS TRIGGER
AS $ $
DECLARE
i INTEGER ;
existing RECORD ;
existingplacex RECORD ;
2016-04-25 10:44:01 +03:00
existingline RECORD ;
2010-10-24 03:12:37 +04:00
existinggeometry GEOMETRY ;
2011-06-14 17:42:46 +04:00
existingplace_id BIGINT ;
2010-10-24 03:12:37 +04:00
result BOOLEAN ;
2011-01-05 17:07:26 +03:00
partition INTEGER ;
2010-10-24 03:12:37 +04:00
BEGIN
2012-05-22 18:27:42 +04:00
- - DEBUG : RAISE WARNING ' ----------------------------------------------------------------------------------- ' ;
- - DEBUG : RAISE WARNING ' place_insert: % % % % % ' , NEW . osm_type , NEW . osm_id , NEW . class , NEW . type , st_area ( NEW . geometry ) ;
2016-04-25 10:44:01 +03:00
-- filter wrong tupels
2010-10-24 03:12:37 +04:00
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
2017-04-14 16:50:27 +03:00
INSERT INTO import_polygon_error ( osm_type , osm_id , class , type , name , country_code , updated , errormessage , prevgeometry , newgeometry )
VALUES ( NEW . osm_type , NEW . osm_id , NEW . class , NEW . type , NEW . name , NEW . address - > ' country ' , now ( ) , ST_IsValidReason ( NEW . geometry ) , null , NEW . geometry ) ;
2010-10-24 03:12:37 +04:00
-- RAISE WARNING 'Invalid Geometry: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
RETURN null ;
END IF ;
2016-05-15 13:37:20 +03:00
2017-02-26 14:58:07 +03:00
-- decide, whether it is an osm interpolation line => insert intoosmline, or else just placex
2016-05-15 13:37:20 +03:00
IF NEW . class = ' place ' and NEW . type = ' houses ' and NEW . osm_type = ' W ' and ST_GeometryType ( NEW . geometry ) = ' ST_LineString ' THEN
2016-04-25 10:44:01 +03:00
-- Have we already done this place?
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 ;
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
-- Get the existing place_id
select * from location_property_osmline where osm_id = NEW . osm_id INTO existingline ;
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
-- Handle a place changing type by removing the old data (this trigger is executed BEFORE INSERT of the NEW tupel)
IF existing . osm_type IS NULL THEN
DELETE FROM place where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class ;
END IF ;
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
DELETE from import_polygon_error where osm_type = NEW . osm_type and osm_id = NEW . osm_id ;
DELETE from import_polygon_delete where osm_type = NEW . osm_type and osm_id = NEW . osm_id ;
2016-05-15 13:37:20 +03:00
2016-05-28 19:18:18 +03:00
-- 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)
IF existingline . osm_id IS NOT NULL THEN
delete from location_property_osmline where osm_id = NEW . osm_id ;
END IF ;
-- for interpolations invalidate all nodes on the line
update placex p set indexed_status = 2
from planet_osm_ways w
where w . id = NEW . osm_id and p . osm_type = ' N ' and p . osm_id = any ( w . nodes ) ;
2017-02-26 14:58:07 +03:00
2017-03-26 01:11:09 +03:00
INSERT INTO location_property_osmline ( osm_id , address , linegeo )
VALUES ( NEW . osm_id , NEW . address , NEW . geometry ) ;
2016-05-28 19:18:18 +03:00
IF existing . osm_type IS NULL THEN
return NEW ;
2016-04-25 10:44:01 +03:00
END IF ;
2016-05-15 13:37:20 +03:00
2017-03-26 01:11:09 +03:00
IF coalesce ( existing . address , ' ' : : hstore ) ! = coalesce ( NEW . address , ' ' : : hstore )
OR ( coalesce ( existing . extratags , ' ' : : hstore ) ! = coalesce ( NEW . extratags , ' ' : : hstore ) )
2016-04-25 10:44:01 +03:00
OR existing . geometry : : text ! = NEW . geometry : : text
THEN
update place set
name = NEW . name ,
2017-03-26 01:11:09 +03:00
address = NEW . address ,
2016-04-25 10:44:01 +03:00
extratags = NEW . extratags ,
admin_level = NEW . admin_level ,
geometry = NEW . geometry
where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class and type = NEW . type ;
END IF ;
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
RETURN NULL ;
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
ELSE -- insert to placex
2016-05-15 13:37:20 +03:00
2016-04-25 10:44:01 +03:00
-- Patch in additional country names
2017-03-26 22:19:52 +03:00
IF NEW . admin_level = 2 AND NEW . type = ' administrative '
AND NEW . address is not NULL AND NEW . address ? ' country ' THEN
2017-03-26 01:11:09 +03:00
SELECT name FROM country_name WHERE country_code = lower ( NEW . address - > ' country ' ) INTO existing ;
2017-02-18 15:51:21 +03:00
IF existing . name IS NOT NULL THEN
NEW . name = existing . name | | NEW . name ;
END IF ;
2016-04-25 10:44:01 +03:00
END IF ;
-- Have we already done this place?
select * from place where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class and type = NEW . type INTO existing ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Get the existing place_id
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 ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Handle a place changing type by removing the old data
-- My generated 'place' types are causing havok because they overlap with real keys
-- TODO: move them to their own special purpose key/class to avoid collisions
IF existing . osm_type IS NULL THEN
DELETE FROM place where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
- - DEBUG : RAISE WARNING ' Existing: % ' , existing . osm_id ;
- - DEBUG : RAISE WARNING ' Existing PlaceX: % ' , existingplacex . place_id ;
-- Log and discard
IF existing . geometry is not null AND st_isvalid ( existing . geometry )
AND st_area ( existing . geometry ) > 0 . 02
AND ST_GeometryType ( NEW . geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' )
AND st_area ( NEW . geometry ) < st_area ( existing . geometry ) * 0 . 5
THEN
2017-04-14 16:50:27 +03:00
INSERT INTO import_polygon_error ( osm_type , osm_id , class , type , name , country_code , updated , errormessage , prevgeometry , newgeometry )
2017-04-23 23:46:54 +03:00
VALUES ( NEW . osm_type , NEW . osm_id , NEW . class , NEW . type , NEW . name , NEW . address - > ' country ' , now ( ) ,
2016-04-25 10:44:01 +03:00
' Area reduced from ' | | st_area ( existing . geometry ) | | ' to ' | | st_area ( NEW . geometry ) , existing . geometry , NEW . geometry ) ;
RETURN null ;
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
DELETE from import_polygon_error where osm_type = NEW . osm_type and osm_id = NEW . osm_id ;
DELETE from import_polygon_delete where osm_type = NEW . osm_type and osm_id = NEW . osm_id ;
-- To paraphrase, if there isn't an existing item, OR if the admin level has changed
IF existingplacex . osm_type IS NULL OR
2018-02-12 23:19:27 +03:00
( existingplacex . class = ' boundary ' AND
( ( coalesce ( existingplacex . admin_level , 15 ) ! = coalesce ( NEW . admin_level , 15 ) AND existingplacex . type = ' administrative ' ) OR
( existingplacex . type ! = NEW . type ) ) )
2011-02-07 14:13:18 +03:00
THEN
2016-04-25 10:44:01 +03:00
IF existingplacex . osm_type IS NOT NULL THEN
-- sanity check: ignore admin_level changes on places with too many active children
-- or we end up reindexing entire countries because somebody accidentally deleted admin_level
- - 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 ;
- - LIMIT INDEXING : IF i > 100000 THEN
- - LIMIT INDEXING : RETURN null ;
- - LIMIT INDEXING : END IF ;
END IF ;
2011-02-07 14:13:18 +03:00
2016-04-25 10:44:01 +03:00
IF existing . osm_type IS NOT NULL THEN
-- pathological case caused by the triggerless copy into place during initial import
-- force delete even for large areas, it will be reinserted later
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 ;
DELETE from place where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class and type = NEW . type ;
END IF ;
2014-02-08 02:37:54 +04:00
2016-04-25 10:44:01 +03:00
-- No - process it as a new insertion (hopefully of low rank or it will be slow)
2017-03-26 01:11:09 +03:00
insert into placex ( osm_type , osm_id , class , type , name ,
admin_level , address , extratags , geometry )
values ( NEW . osm_type , NEW . osm_id , NEW . class , NEW . type , NEW . name ,
NEW . admin_level , NEW . address , NEW . extratags , NEW . geometry ) ;
2016-04-25 10:44:01 +03:00
- - DEBUG : RAISE WARNING ' insert done % % % % % ' , NEW . osm_type , NEW . osm_id , NEW . class , NEW . type , NEW . name ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
RETURN NEW ;
2012-05-22 18:27:42 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Special case for polygon shape changes because they tend to be large and we can be a bit clever about how we handle them
IF existing . geometry : : text ! = NEW . geometry : : text
AND ST_GeometryType ( existing . geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' )
AND ST_GeometryType ( NEW . geometry ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' )
THEN
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Get the version of the geometry actually used (in placex table)
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 ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- Performance limit
IF st_area ( NEW . geometry ) < 0 . 000000001 AND st_area ( existinggeometry ) < 1 THEN
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
-- 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
update placex set indexed_status = 2 where indexed_status = 0 and
( st_covers ( NEW . geometry , placex . geometry ) OR ST_Intersects ( NEW . geometry , placex . geometry ) )
AND NOT ( st_covers ( existinggeometry , placex . geometry ) OR ST_Intersects ( existinggeometry , placex . geometry ) )
AND rank_search > existingplacex . rank_search AND ( rank_search < 28 or name is not null ) ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
update placex set indexed_status = 2 where indexed_status = 0 and
( st_covers ( existinggeometry , placex . geometry ) OR ST_Intersects ( existinggeometry , placex . geometry ) )
AND NOT ( st_covers ( NEW . geometry , placex . geometry ) OR ST_Intersects ( NEW . geometry , placex . geometry ) )
AND rank_search > existingplacex . rank_search AND ( rank_search < 28 or name is not null ) ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2016-04-25 10:44:01 +03:00
IF coalesce ( existing . name : : text , ' ' ) ! = coalesce ( NEW . name : : text , ' ' )
OR coalesce ( existing . extratags : : text , ' ' ) ! = coalesce ( NEW . extratags : : text , ' ' )
2017-03-26 01:11:09 +03:00
OR coalesce ( existing . address , ' ' : : hstore ) ! = coalesce ( NEW . address , ' ' : : hstore )
2016-04-25 10:44:01 +03:00
OR coalesce ( existing . admin_level , 15 ) ! = coalesce ( NEW . admin_level , 15 )
OR existing . geometry : : text ! = NEW . geometry : : text
THEN
update place set
name = NEW . name ,
2017-03-26 01:11:09 +03:00
address = NEW . address ,
2016-04-25 10:44:01 +03:00
extratags = NEW . extratags ,
admin_level = NEW . admin_level ,
geometry = NEW . geometry
where osm_type = NEW . osm_type and osm_id = NEW . osm_id and class = NEW . class and type = NEW . type ;
2017-03-26 01:11:09 +03:00
2016-04-25 10:44:01 +03:00
IF NEW . class in ( ' place ' , ' boundary ' ) AND NEW . type in ( ' postcode ' , ' postal_code ' ) THEN
2017-03-30 22:57:34 +03:00
IF NEW . address is NULL OR NOT NEW . address ? ' postcode ' THEN
2016-04-25 10:44:01 +03:00
-- postcode was deleted, no longer retain in placex
DELETE FROM placex where place_id = existingplacex . place_id ;
RETURN NULL ;
END IF ;
2010-10-24 03:12:37 +04:00
2017-03-30 22:57:34 +03:00
NEW . name : = hstore ( ' ref ' , NEW . address - > ' postcode ' ) ;
2016-04-25 10:44:01 +03:00
END IF ;
2017-03-26 01:11:09 +03:00
2017-06-06 22:58:41 +03:00
IF NEW . class in ( ' boundary ' )
AND ST_GeometryType ( NEW . geometry ) not in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
DELETE FROM placex where place_id = existingplacex . place_id ;
RETURN NULL ;
END IF ;
2016-04-25 10:44:01 +03:00
update placex set
name = NEW . name ,
2017-03-26 01:11:09 +03:00
address = NEW . address ,
2016-04-25 10:44:01 +03:00
parent_place_id = null ,
extratags = NEW . extratags ,
2017-03-26 01:11:09 +03:00
admin_level = NEW . admin_level ,
indexed_status = 2 ,
2016-04-25 10:44:01 +03:00
geometry = NEW . geometry
where place_id = existingplacex . place_id ;
2016-04-27 18:42:59 +03:00
-- if a node(=>house), which is part of a interpolation line, changes (e.g. the street attribute) => mark this line for reparenting
-- (already here, because interpolation lines are reindexed before nodes, so in the second call it would be too late)
2019-07-04 00:15:54 +03:00
IF NEW . osm_type = ' N '
and ( coalesce ( existing . address , ' ' : : hstore ) ! = coalesce ( NEW . address , ' ' : : hstore )
or existing . geometry : : text ! = NEW . geometry : : text )
THEN
result : = osmline_reinsert ( NEW . osm_id , NEW . geometry ) ;
2016-04-27 18:42:59 +03:00
END IF ;
2014-03-24 16:01:20 +04:00
2017-06-07 00:46:44 +03:00
-- linked places should get potential new naming and addresses
IF existingplacex . linked_place_id is not NULL THEN
update placex x set
name = p . name ,
extratags = p . extratags ,
indexed_status = 2
from place p
where x . place_id = existingplacex . linked_place_id
and x . indexed_status = 0
and x . osm_type = p . osm_type
and x . osm_id = p . osm_id
and x . class = p . class ;
END IF ;
2014-03-24 16:01:20 +04:00
END IF ;
2016-04-25 10:44:01 +03:00
-- Abort the add (we modified the existing place instead)
RETURN NULL ;
2015-02-24 01:29:31 +03:00
END IF ;
2016-04-27 18:42:59 +03:00
END ;
2010-10-24 03:12:37 +04:00
$ $ LANGUAGE plpgsql ;
2015-09-25 00:52:03 +03:00
2010-10-26 19:22:41 +04:00
CREATE OR REPLACE FUNCTION get_name_by_language ( name hstore , languagepref TEXT [ ] ) RETURNS TEXT
2010-10-24 03:12:37 +04:00
AS $ $
DECLARE
2015-09-25 00:52:03 +03:00
result TEXT ;
2010-10-24 03:12:37 +04:00
BEGIN
2010-10-27 18:05:42 +04:00
IF name is null THEN
RETURN null ;
2010-10-24 03:12:37 +04:00
END IF ;
2015-09-25 00:52:03 +03:00
FOR j IN 1 . . array_upper ( languagepref , 1 ) LOOP
IF name ? languagepref [ j ] THEN
result : = trim ( name - > languagepref [ j ] ) ;
IF result ! = ' ' THEN
return result ;
END IF ;
2010-10-26 19:22:41 +04:00
END IF ;
2010-10-24 03:12:37 +04:00
END LOOP ;
2012-12-12 06:09:18 +04:00
-- anything will do as a fallback - just take the first name type thing there is
2015-09-25 00:52:03 +03:00
RETURN trim ( ( avals ( name ) ) [ 1 ] ) ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql IMMUTABLE ;
2016-03-10 18:22:39 +03:00
- - housenumber only needed for tiger data
CREATE OR REPLACE FUNCTION get_address_by_language ( for_place_id BIGINT , housenumber INTEGER , languagepref TEXT [ ] ) RETURNS TEXT
2010-10-24 03:12:37 +04:00
AS $ $
DECLARE
result TEXT [ ] ;
2011-01-05 17:07:26 +03:00
currresult TEXT ;
prevresult TEXT ;
2010-10-24 03:12:37 +04:00
location RECORD ;
BEGIN
result : = ' {} ' ;
2011-01-05 17:07:26 +03:00
prevresult : = ' ' ;
2010-10-24 03:12:37 +04:00
2016-03-23 11:34:36 +03:00
FOR location IN select * from get_addressdata ( for_place_id , housenumber ) where isaddress order by rank_address desc LOOP
2011-01-05 17:07:26 +03:00
currresult : = trim ( get_name_by_language ( location . name , languagepref ) ) ;
2012-08-20 01:08:51 +04:00
IF currresult ! = prevresult AND currresult IS NOT NULL AND result [ ( 100 - location . rank_address ) ] IS NULL THEN
2011-01-05 17:07:26 +03:00
result [ ( 100 - location . rank_address ) ] : = trim ( get_name_by_language ( location . name , languagepref ) ) ;
prevresult : = currresult ;
2010-10-24 03:12:37 +04:00
END IF ;
END LOOP ;
RETURN array_to_string ( result , ' , ' ) ;
END ;
$ $
LANGUAGE plpgsql ;
2013-04-10 00:44:05 +04:00
DROP TYPE IF EXISTS addressline CASCADE ;
2011-01-05 17:07:26 +03:00
create type addressline as (
2011-06-14 17:42:46 +04:00
place_id BIGINT ,
2011-01-05 17:07:26 +03:00
osm_type CHAR ( 1 ) ,
2013-02-12 17:28:07 +04:00
osm_id BIGINT ,
2011-01-05 17:07:26 +03:00
name HSTORE ,
class TEXT ,
type TEXT ,
2011-02-07 14:13:18 +03:00
admin_level INTEGER ,
2011-01-05 17:07:26 +03:00
fromarea BOOLEAN ,
isaddress BOOLEAN ,
rank_address INTEGER ,
distance FLOAT
) ;
2019-01-13 23:07:01 +03:00
-- Compute the list of address parts for the given place.
--
-- If in_housenumber is greator or equal 0, look for an interpolation.
2016-03-10 18:22:39 +03:00
CREATE OR REPLACE FUNCTION get_addressdata ( in_place_id BIGINT , in_housenumber INTEGER ) RETURNS setof addressline
2010-10-24 03:12:37 +04:00
AS $ $
DECLARE
2016-04-25 10:44:01 +03:00
for_place_id BIGINT ;
2010-10-24 03:12:37 +04:00
result TEXT [ ] ;
search TEXT [ ] ;
found INTEGER ;
location RECORD ;
2011-02-07 14:13:18 +03:00
countrylocation RECORD ;
2010-10-24 03:12:37 +04:00
searchcountrycode varchar ( 2 ) ;
searchhousenumber TEXT ;
2011-01-05 17:07:26 +03:00
searchhousename HSTORE ;
searchrankaddress INTEGER ;
searchpostcode TEXT ;
2019-04-14 12:20:03 +03:00
postcode_isaddress BOOL ;
2011-02-07 14:13:18 +03:00
searchclass TEXT ;
searchtype TEXT ;
2011-01-05 17:07:26 +03:00
countryname HSTORE ;
2010-10-24 03:12:37 +04:00
BEGIN
2019-01-13 23:07:01 +03:00
-- The place ein question might not have a direct entry in place_addressline.
-- Look for the parent of such places then and save if in for_place_id.
2019-04-14 12:20:03 +03:00
postcode_isaddress : = true ;
2016-04-25 10:44:01 +03:00
-- first query osmline (interpolation lines)
2019-01-13 23:07:01 +03:00
IF in_housenumber > = 0 THEN
SELECT parent_place_id , country_code , in_housenumber : : text , 30 , postcode ,
null , ' place ' , ' house '
FROM location_property_osmline
WHERE place_id = in_place_id AND in_housenumber > = startnumber
AND in_housenumber < = endnumber
INTO for_place_id , searchcountrycode , searchhousenumber , searchrankaddress ,
searchpostcode , searchhousename , searchclass , searchtype ;
2016-03-10 18:22:39 +03:00
END IF ;
2016-04-25 12:01:04 +03:00
2016-04-25 10:44:01 +03:00
- - then query tiger data
2016-04-25 12:01:04 +03:00
-- %NOTIGERDATA% IF 0 THEN
2019-01-13 23:07:01 +03:00
IF for_place_id IS NULL AND in_housenumber > = 0 THEN
SELECT parent_place_id , ' us ' , in_housenumber : : text , 30 , postcode , null ,
' place ' , ' house '
FROM location_property_tiger
WHERE place_id = in_place_id AND in_housenumber > = startnumber
AND in_housenumber < = endnumber
INTO for_place_id , searchcountrycode , searchhousenumber , searchrankaddress ,
searchpostcode , searchhousename , searchclass , searchtype ;
2016-04-25 10:44:01 +03:00
END IF ;
2016-04-07 22:47:51 +03:00
-- %NOTIGERDATA% END IF;
-- %NOAUXDATA% IF 0 THEN
2011-01-05 17:07:26 +03:00
IF for_place_id IS NULL THEN
2019-01-13 23:07:01 +03:00
SELECT parent_place_id , ' us ' , housenumber , 30 , postcode , null , ' place ' , ' house '
FROM location_property_aux
2017-07-05 00:25:48 +03:00
WHERE place_id = in_place_id
2019-01-13 23:07:01 +03:00
INTO for_place_id , searchcountrycode , searchhousenumber , searchrankaddress ,
searchpostcode , searchhousename , searchclass , searchtype ;
2011-01-21 13:40:44 +03:00
END IF ;
2016-04-07 22:47:51 +03:00
-- %NOAUXDATA% END IF;
2010-10-24 03:12:37 +04:00
2017-07-05 00:25:48 +03:00
-- postcode table
IF for_place_id IS NULL THEN
2019-10-19 18:57:57 +03:00
SELECT parent_place_id , country_code , rank_search , postcode , ' place ' , ' postcode '
2017-07-05 00:25:48 +03:00
FROM location_postcode
WHERE place_id = in_place_id
2019-01-13 23:07:01 +03:00
INTO for_place_id , searchcountrycode , searchrankaddress , searchpostcode ,
searchclass , searchtype ;
2017-07-05 00:25:48 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2019-01-13 23:07:01 +03:00
-- POI objects in the placex table
2011-01-21 13:40:44 +03:00
IF for_place_id IS NULL THEN
2019-01-13 23:07:01 +03:00
SELECT parent_place_id , country_code , housenumber , rank_search , postcode ,
name , class , type
FROM placex
WHERE place_id = in_place_id and rank_search > 27
INTO for_place_id , searchcountrycode , searchhousenumber , searchrankaddress ,
searchpostcode , searchhousename , searchclass , searchtype ;
2011-01-21 13:40:44 +03:00
END IF ;
2010-10-24 03:12:37 +04:00
2019-01-13 23:07:01 +03:00
-- If for_place_id is still NULL at this point then the object has its own
-- entry in place_address line. However, still check if there is not linked
-- place we should be using instead.
2011-01-21 13:40:44 +03:00
IF for_place_id IS NULL THEN
2017-03-26 01:11:09 +03:00
select coalesce ( linked_place_id , place_id ) , country_code ,
2015-05-03 18:31:14 +03:00
housenumber , rank_search , postcode , null
from placex where place_id = in_place_id
INTO for_place_id , searchcountrycode , searchhousenumber , searchrankaddress , searchpostcode , searchhousename ;
2011-01-05 17:07:26 +03:00
END IF ;
2011-01-21 13:40:44 +03:00
2011-01-05 17:07:26 +03:00
- - RAISE WARNING ' % % % % ' , searchcountrycode , searchhousenumber , searchrankaddress , searchpostcode ;
2010-10-24 03:12:37 +04:00
2019-01-13 23:07:01 +03:00
found : = 1000 ; -- the lowest rank_address included
-- Return the record for the base entry.
FOR location IN
SELECT placex . place_id , osm_type , osm_id , name ,
class , type , admin_level ,
type not in ( ' postcode ' , ' postal_code ' ) as isaddress ,
CASE WHEN rank_address = 0 THEN 100
WHEN rank_address = 11 THEN 5
ELSE rank_address END as rank_address ,
0 as distance , country_code , postcode
FROM placex
WHERE place_id = for_place_id
2011-03-11 17:03:18 +03:00
LOOP
- - RAISE WARNING ' % ' , location ;
2017-03-26 01:11:09 +03:00
IF searchcountrycode IS NULL AND location . country_code IS NOT NULL THEN
searchcountrycode : = location . country_code ;
2011-03-11 17:03:18 +03:00
END IF ;
2019-01-13 23:07:01 +03:00
IF location . rank_address < 4 THEN
-- no country locations for ranks higher than country
searchcountrycode : = NULL ;
2011-03-11 17:03:18 +03:00
END IF ;
2019-01-13 23:07:01 +03:00
countrylocation : = ROW ( location . place_id , location . osm_type , location . osm_id ,
location . name , location . class , location . type ,
location . admin_level , true , location . isaddress ,
location . rank_address , location . distance ) : : addressline ;
2011-03-11 17:03:18 +03:00
RETURN NEXT countrylocation ;
found : = location . rank_address ;
END LOOP ;
2019-01-13 23:07:01 +03:00
FOR location IN
SELECT placex . place_id , osm_type , osm_id , name ,
CASE WHEN extratags ? ' place ' THEN ' place ' ELSE class END as class ,
CASE WHEN extratags ? ' place ' THEN extratags - > ' place ' ELSE type END as type ,
admin_level , fromarea , isaddress ,
CASE WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address ,
distance , country_code , postcode
FROM place_addressline join placex on ( address_place_id = placex . place_id )
WHERE place_addressline . place_id = for_place_id
AND ( cached_rank_address > = 4 AND cached_rank_address < searchrankaddress )
AND linked_place_id is null
AND ( placex . country_code IS NULL OR searchcountrycode IS NULL
OR placex . country_code = searchcountrycode )
ORDER BY rank_address desc , isaddress desc , fromarea desc ,
distance asc , rank_search desc
2010-10-24 03:12:37 +04:00
LOOP
2011-01-05 17:07:26 +03:00
- - RAISE WARNING ' % ' , location ;
2017-03-26 01:11:09 +03:00
IF searchcountrycode IS NULL AND location . country_code IS NOT NULL THEN
searchcountrycode : = location . country_code ;
2011-02-07 14:13:18 +03:00
END IF ;
2017-07-02 15:16:48 +03:00
IF location . type in ( ' postcode ' , ' postal_code ' ) THEN
2019-04-14 12:20:03 +03:00
postcode_isaddress : = false ;
IF location . osm_type ! = ' R ' THEN
location . isaddress : = FALSE ;
END IF ;
2010-10-24 03:12:37 +04:00
END IF ;
2019-01-13 23:07:01 +03:00
countrylocation : = ROW ( location . place_id , location . osm_type , location . osm_id ,
location . name , location . class , location . type ,
location . admin_level , location . fromarea ,
location . isaddress , location . rank_address ,
2011-02-07 14:13:18 +03:00
location . distance ) : : addressline ;
RETURN NEXT countrylocation ;
2011-01-05 17:07:26 +03:00
found : = location . rank_address ;
2010-10-24 03:12:37 +04:00
END LOOP ;
2019-01-13 23:07:01 +03:00
-- If no country was included yet, add the name information from country_name.
2010-10-24 03:12:37 +04:00
IF found > 4 THEN
2019-01-13 23:07:01 +03:00
SELECT name FROM country_name
WHERE country_code = searchcountrycode LIMIT 1 INTO countryname ;
2011-01-05 17:07:26 +03:00
- - RAISE WARNING ' % % % ' , found , searchcountrycode , countryname ;
IF countryname IS NOT NULL THEN
2019-01-13 23:07:01 +03:00
location : = ROW ( null , null , null , countryname , ' place ' , ' country ' ,
null , true , true , 4 , 0 ) : : addressline ;
2011-01-05 17:07:26 +03:00
RETURN NEXT location ;
2010-10-24 03:12:37 +04:00
END IF ;
END IF ;
2019-01-13 23:07:01 +03:00
-- Finally add some artificial rows.
2011-01-05 17:07:26 +03:00
IF searchcountrycode IS NOT NULL THEN
2019-01-13 23:07:01 +03:00
location : = ROW ( null , null , null , hstore ( ' ref ' , searchcountrycode ) ,
' place ' , ' country_code ' , null , true , false , 4 , 0 ) : : addressline ;
2011-01-05 17:07:26 +03:00
RETURN NEXT location ;
END IF ;
IF searchhousename IS NOT NULL THEN
2019-01-13 23:07:01 +03:00
location : = ROW ( in_place_id , null , null , searchhousename , searchclass ,
searchtype , null , true , true , 29 , 0 ) : : addressline ;
2011-01-05 17:07:26 +03:00
RETURN NEXT location ;
END IF ;
IF searchhousenumber IS NOT NULL THEN
2019-01-13 23:07:01 +03:00
location : = ROW ( in_place_id , null , null , hstore ( ' ref ' , searchhousenumber ) ,
' place ' , ' house_number ' , null , true , true , 28 , 0 ) : : addressline ;
2011-01-05 17:07:26 +03:00
RETURN NEXT location ;
END IF ;
IF searchpostcode IS NOT NULL THEN
2019-01-13 23:07:01 +03:00
location : = ROW ( null , null , null , hstore ( ' ref ' , searchpostcode ) , ' place ' ,
2019-04-14 12:20:03 +03:00
' postcode ' , null , false , postcode_isaddress , 5 , 0 ) : : addressline ;
2011-01-05 17:07:26 +03:00
RETURN NEXT location ;
END IF ;
RETURN ;
2010-10-24 03:12:37 +04:00
END ;
$ $
LANGUAGE plpgsql ;
2011-01-21 13:40:44 +03:00
CREATE OR REPLACE FUNCTION aux_create_property ( pointgeo GEOMETRY , in_housenumber TEXT ,
in_street TEXT , in_isin TEXT , in_postcode TEXT , in_countrycode char ( 2 ) ) RETURNS INTEGER
AS $ $
DECLARE
newpoints INTEGER ;
place_centroid GEOMETRY ;
2012-03-30 01:48:29 +04:00
out_partition INTEGER ;
2011-06-14 17:42:46 +04:00
out_parent_place_id BIGINT ;
2011-01-21 13:40:44 +03:00
location RECORD ;
address_street_word_id INTEGER ;
2011-06-14 17:42:46 +04:00
out_postcode TEXT ;
2011-01-21 13:40:44 +03:00
BEGIN
place_centroid : = ST_Centroid ( pointgeo ) ;
2014-04-11 00:55:49 +04:00
out_partition : = get_partition ( in_countrycode ) ;
2011-06-14 17:42:46 +04:00
out_parent_place_id : = null ;
2011-01-21 13:40:44 +03:00
address_street_word_id : = get_name_id ( make_standard_name ( in_street ) ) ;
IF address_street_word_id IS NOT NULL THEN
2012-03-30 01:48:29 +04:00
FOR location IN SELECT * from getNearestNamedRoadFeature ( out_partition , place_centroid , address_street_word_id ) LOOP
2011-06-14 17:42:46 +04:00
out_parent_place_id : = location . place_id ;
2011-01-21 13:40:44 +03:00
END LOOP ;
END IF ;
2011-06-14 17:42:46 +04:00
IF out_parent_place_id IS NULL THEN
2012-03-30 01:48:29 +04:00
FOR location IN SELECT place_id FROM getNearestRoadFeature ( out_partition , place_centroid ) LOOP
2011-06-14 17:42:46 +04:00
out_parent_place_id : = location . place_id ;
2017-03-26 01:11:09 +03:00
END LOOP ;
2011-01-21 13:40:44 +03:00
END IF ;
2011-06-14 17:42:46 +04:00
out_postcode : = in_postcode ;
IF out_postcode IS NULL THEN
SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode ;
END IF ;
2017-06-30 00:13:40 +03:00
-- XXX look into postcode table
2011-06-14 17:42:46 +04:00
2011-01-21 13:40:44 +03:00
newpoints : = 0 ;
insert into location_property_aux ( place_id , partition , parent_place_id , housenumber , postcode , centroid )
2012-03-30 01:48:29 +04:00
values ( nextval ( ' seq_place ' ) , out_partition , out_parent_place_id , in_housenumber , out_postcode , place_centroid ) ;
2011-01-21 13:40:44 +03:00
newpoints : = newpoints + 1 ;
RETURN newpoints ;
END ;
$ $
LANGUAGE plpgsql ;
2012-04-01 04:40:50 +04:00
CREATE OR REPLACE FUNCTION get_osm_rel_members ( members TEXT [ ] , member TEXT ) RETURNS TEXT [ ]
AS $ $
DECLARE
result TEXT [ ] ;
i INTEGER ;
BEGIN
FOR i IN 1 . . ARRAY_UPPER ( members , 1 ) BY 2 LOOP
IF members [ i + 1 ] = member THEN
result : = result | | members [ i ] ;
END IF ;
END LOOP ;
return result ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION get_osm_rel_members ( members TEXT [ ] , memberLabels TEXT [ ] ) RETURNS SETOF TEXT
AS $ $
DECLARE
i INTEGER ;
BEGIN
FOR i IN 1 . . ARRAY_UPPER ( members , 1 ) BY 2 LOOP
IF members [ i + 1 ] = ANY ( memberLabels ) THEN
RETURN NEXT members [ i ] ;
END IF ;
END LOOP ;
RETURN ;
END ;
$ $
LANGUAGE plpgsql ;
2012-04-30 04:05:06 +04:00
-- See: http://stackoverflow.com/questions/6410088/how-can-i-mimic-the-php-urldecode-function-in-postgresql
CREATE OR REPLACE FUNCTION decode_url_part ( p varchar ) RETURNS varchar
AS $ $
2012-05-04 03:58:26 +04:00
SELECT convert_from ( CAST ( E ' \\x ' | | array_to_string ( ARRAY (
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
FROM regexp_matches ( $ 1 , ' %[0-9a-f][0-9a-f]|. ' , ' gi ' ) AS r ( m )
) , ' ' ) AS bytea ) , ' UTF8 ' ) ;
2012-04-30 04:05:06 +04:00
$ $
LANGUAGE SQL IMMUTABLE STRICT ;
2012-05-04 03:58:26 +04:00
CREATE OR REPLACE FUNCTION catch_decode_url_part ( p varchar ) RETURNS varchar
AS $ $
DECLARE
BEGIN
RETURN decode_url_part ( p ) ;
EXCEPTION
WHEN others THEN return null ;
END ;
$ $
2012-05-05 13:38:26 +04:00
LANGUAGE plpgsql IMMUTABLE ;
2012-05-07 03:18:31 +04:00
DROP TYPE wikipedia_article_match CASCADE ;
create type wikipedia_article_match as (
language TEXT ,
title TEXT ,
importance FLOAT
) ;
2012-05-11 21:23:44 +04:00
CREATE OR REPLACE FUNCTION get_wikipedia_match ( extratags HSTORE , country_code varchar ( 2 ) ) RETURNS wikipedia_article_match
2012-05-07 03:18:31 +04:00
AS $ $
DECLARE
langs TEXT [ ] ;
i INT ;
wiki_article TEXT ;
wiki_article_title TEXT ;
wiki_article_language TEXT ;
result wikipedia_article_match ;
BEGIN
2012-05-11 21:23:44 +04:00
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 ' ] ;
2012-05-07 03:18:31 +04:00
i : = 1 ;
WHILE langs [ i ] IS NOT NULL LOOP
2012-05-11 21:23:44 +04:00
wiki_article : = extratags - > ( case when langs [ i ] in ( ' english ' , ' country ' ) THEN ' wikipedia ' ELSE ' wikipedia: ' | | langs [ i ] END ) ;
2012-05-07 03:18:31 +04:00
IF wiki_article is not null THEN
2012-05-11 21:23:44 +04:00
wiki_article : = regexp_replace ( wiki_article , E ' ^(.*?)([a-z]{2,3}).wikipedia.org/wiki/ ' , E ' \\2: ' ) ;
wiki_article : = regexp_replace ( wiki_article , E ' ^(.*?)([a-z]{2,3}).wikipedia.org/w/index.php\\?title= ' , E ' \\2: ' ) ;
wiki_article : = regexp_replace ( wiki_article , E ' ^(.*?)/([a-z]{2,3})/wiki/ ' , E ' \\2: ' ) ;
2014-08-18 00:31:18 +04:00
- - wiki_article : = regexp_replace ( wiki_article , E ' ^(.*?)([a-z]{2,3})[=:] ' , E ' \\2: ' ) ;
2012-05-11 21:23:44 +04:00
wiki_article : = replace ( wiki_article , ' ' , ' _ ' ) ;
2014-08-18 00:31:18 +04:00
IF strpos ( wiki_article , ' : ' ) IN ( 3 , 4 ) THEN
wiki_article_language : = lower ( trim ( split_part ( wiki_article , ' : ' , 1 ) ) ) ;
wiki_article_title : = trim ( substr ( wiki_article , strpos ( wiki_article , ' : ' ) + 1 ) ) ;
ELSE
2012-05-11 21:23:44 +04:00
wiki_article_title : = trim ( wiki_article ) ;
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 ;
2012-05-07 03:18:31 +04:00
END IF ;
select wikipedia_article . language , wikipedia_article . title , wikipedia_article . importance
from wikipedia_article
where language = wiki_article_language and
( title = wiki_article_title OR title = catch_decode_url_part ( wiki_article_title ) OR title = replace ( catch_decode_url_part ( wiki_article_title ) , E ' \\ ' , ' ' ) )
UNION ALL
select wikipedia_article . language , wikipedia_article . title , wikipedia_article . importance
from wikipedia_redirect join wikipedia_article on ( wikipedia_redirect . language = wikipedia_article . language and wikipedia_redirect . to_title = wikipedia_article . title )
where wikipedia_redirect . language = wiki_article_language and
( 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 ' \\ ' , ' ' ) )
order by importance desc limit 1 INTO result ;
IF result . language is not null THEN
return result ;
END IF ;
END IF ;
i : = i + 1 ;
END LOOP ;
RETURN NULL ;
END ;
$ $
2019-10-28 00:18:05 +03:00
LANGUAGE plpgsql ;
DROP TYPE IF EXISTS place_importance CASCADE ;
create type place_importance as (
importance FLOAT ,
wikipedia TEXT
) ;
CREATE OR REPLACE FUNCTION compute_importance ( extratags HSTORE , country_code varchar ( 2 ) , osm_type varchar ( 1 ) , osm_id BIGINT )
RETURNS place_importance
AS $ $
DECLARE
match RECORD ;
result place_importance ;
BEGIN
2019-11-17 12:06:34 +03:00
FOR match IN SELECT * FROM get_wikipedia_match ( extratags , country_code )
WHERE language is not NULL
LOOP
2019-10-28 00:18:05 +03:00
result . importance : = match . importance ;
result . wikipedia : = match . language | | ' : ' | | match . title ;
RETURN result ;
END LOOP ;
2019-10-31 23:00:28 +03:00
IF extratags ? ' wikidata ' THEN
FOR match IN SELECT * FROM wikipedia_article
WHERE wd_page_title = extratags - > ' wikidata '
ORDER BY importance DESC limit 1 LOOP
result . importance : = match . importance ;
result . wikipedia : = match . language | | ' : ' | | match . title ;
RETURN result ;
END LOOP ;
END IF ;
2019-10-28 00:18:05 +03:00
RETURN null ;
END ;
$ $
2012-05-07 03:18:31 +04:00
LANGUAGE plpgsql ;
2012-05-22 18:27:42 +04:00
CREATE OR REPLACE FUNCTION quad_split_geometry ( geometry GEOMETRY , maxarea FLOAT , maxdepth INTEGER )
RETURNS SETOF GEOMETRY
AS $ $
DECLARE
xmin FLOAT ;
ymin FLOAT ;
xmax FLOAT ;
ymax FLOAT ;
xmid FLOAT ;
ymid FLOAT ;
secgeo GEOMETRY ;
secbox GEOMETRY ;
seg INTEGER ;
geo RECORD ;
area FLOAT ;
remainingdepth INTEGER ;
added INTEGER ;
BEGIN
-- RAISE WARNING 'quad_split_geometry: maxarea=%, depth=%',maxarea,maxdepth;
IF ( ST_GeometryType ( geometry ) not in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) OR NOT ST_IsValid ( geometry ) ) THEN
RETURN NEXT geometry ;
RETURN ;
END IF ;
remainingdepth : = maxdepth - 1 ;
area : = ST_AREA ( geometry ) ;
IF remainingdepth < 1 OR area < maxarea THEN
RETURN NEXT geometry ;
RETURN ;
END IF ;
xmin : = st_xmin ( geometry ) ;
xmax : = st_xmax ( geometry ) ;
ymin : = st_ymin ( geometry ) ;
ymax : = st_ymax ( geometry ) ;
secbox : = ST_SetSRID ( ST_MakeBox2D ( ST_Point ( ymin , xmin ) , ST_Point ( ymax , xmax ) ) , 4326 ) ;
-- if the geometry completely covers the box don't bother to slice any more
IF ST_AREA ( secbox ) = area THEN
RETURN NEXT geometry ;
RETURN ;
END IF ;
xmid : = ( xmin + xmax ) / 2 ;
ymid : = ( ymin + ymax ) / 2 ;
added : = 0 ;
FOR seg IN 1 . . 4 LOOP
IF seg = 1 THEN
secbox : = ST_SetSRID ( ST_MakeBox2D ( ST_Point ( xmin , ymin ) , ST_Point ( xmid , ymid ) ) , 4326 ) ;
END IF ;
IF seg = 2 THEN
secbox : = ST_SetSRID ( ST_MakeBox2D ( ST_Point ( xmin , ymid ) , ST_Point ( xmid , ymax ) ) , 4326 ) ;
END IF ;
IF seg = 3 THEN
secbox : = ST_SetSRID ( ST_MakeBox2D ( ST_Point ( xmid , ymin ) , ST_Point ( xmax , ymid ) ) , 4326 ) ;
END IF ;
IF seg = 4 THEN
secbox : = ST_SetSRID ( ST_MakeBox2D ( ST_Point ( xmid , ymid ) , ST_Point ( xmax , ymax ) ) , 4326 ) ;
END IF ;
IF st_intersects ( geometry , secbox ) THEN
secgeo : = st_intersection ( geometry , secbox ) ;
IF NOT ST_IsEmpty ( secgeo ) AND ST_GeometryType ( secgeo ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
2012-05-24 02:25:15 +04:00
FOR geo IN select quad_split_geometry ( secgeo , maxarea , remainingdepth ) as geom LOOP
IF NOT ST_IsEmpty ( geo . geom ) AND ST_GeometryType ( geo . geom ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
2012-05-22 18:27:42 +04:00
added : = added + 1 ;
2012-05-24 02:25:15 +04:00
RETURN NEXT geo . geom ;
2012-05-22 18:27:42 +04:00
END IF ;
END LOOP ;
END IF ;
END IF ;
END LOOP ;
RETURN ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION split_geometry ( geometry GEOMETRY )
RETURNS SETOF GEOMETRY
AS $ $
DECLARE
geo RECORD ;
BEGIN
-- 10000000000 is ~~ 1x1 degree
2012-05-24 02:25:15 +04:00
FOR geo IN select quad_split_geometry ( geometry , 0 . 25 , 20 ) as geom LOOP
RETURN NEXT geo . geom ;
2012-05-22 18:27:42 +04:00
END LOOP ;
RETURN ;
END ;
$ $
LANGUAGE plpgsql ;
2012-11-30 00:43:33 +04:00
CREATE OR REPLACE FUNCTION place_force_delete ( placeid BIGINT ) RETURNS BOOLEAN
AS $ $
DECLARE
osmid BIGINT ;
osmtype character ( 1 ) ;
pclass text ;
ptype text ;
BEGIN
SELECT osm_type , osm_id , class , type FROM placex WHERE place_id = placeid INTO osmtype , osmid , pclass , ptype ;
DELETE FROM import_polygon_delete where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype ;
DELETE FROM import_polygon_error where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype ;
-- force delete from place/placex by making it a very small geometry
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 ;
DELETE FROM place where osm_type = osmtype and osm_id = osmid and class = pclass and type = ptype ;
RETURN TRUE ;
END ;
$ $
LANGUAGE plpgsql ;
CREATE OR REPLACE FUNCTION place_force_update ( placeid BIGINT ) RETURNS BOOLEAN
AS $ $
DECLARE
placegeom GEOMETRY ;
geom GEOMETRY ;
diameter FLOAT ;
rank INTEGER ;
BEGIN
2014-04-21 23:41:17 +04:00
UPDATE placex SET indexed_status = 2 WHERE place_id = placeid ;
2012-11-30 00:43:33 +04:00
SELECT geometry , rank_search FROM placex WHERE place_id = placeid INTO placegeom , rank ;
IF placegeom IS NOT NULL AND ST_IsValid ( placegeom ) THEN
IF ST_GeometryType ( placegeom ) in ( ' ST_Polygon ' , ' ST_MultiPolygon ' ) THEN
FOR geom IN select split_geometry ( placegeom ) FROM placex WHERE place_id = placeid LOOP
update placex set indexed_status = 2 where ( st_covers ( geom , placex . geometry ) OR ST_Intersects ( geom , placex . geometry ) )
2017-08-14 23:34:53 +03:00
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 ' ) ) ;
2012-11-30 00:43:33 +04:00
update placex set indexed_status = 2 where ( st_covers ( geom , placex . geometry ) OR ST_Intersects ( geom , placex . geometry ) )
2017-04-05 23:19:42 +03:00
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 ' ) ) ;
2012-11-30 00:43:33 +04:00
END LOOP ;
ELSE
diameter : = 0 ;
IF rank = 11 THEN
diameter : = 0 . 05 ;
ELSEIF rank < 18 THEN
diameter : = 0 . 1 ;
ELSEIF rank < 20 THEN
diameter : = 0 . 05 ;
ELSEIF rank = 21 THEN
diameter : = 0 . 001 ;
ELSEIF rank < 24 THEN
diameter : = 0 . 02 ;
ELSEIF rank < 26 THEN
diameter : = 0 . 002 ; -- 100 to 200 meters
ELSEIF rank < 28 THEN
diameter : = 0 . 001 ; -- 50 to 100 meters
END IF ;
IF diameter > 0 THEN
2013-05-16 23:59:06 +04:00
IF rank > = 26 THEN
2013-04-30 22:31:48 +04:00
-- roads may cause reparenting for >27 rank places
update placex set indexed_status = 2 where indexed_status = 0 and rank_search > rank and ST_DWithin ( placex . geometry , placegeom , diameter ) ;
2013-05-16 23:59:06 +04:00
ELSEIF rank > = 16 THEN
2013-04-30 22:31:48 +04:00
-- up to rank 16, street-less addresses may need reparenting
2017-04-05 23:19:42 +03:00
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 ' ) ;
2013-04-30 22:31:48 +04:00
ELSE
-- for all other places the search terms may change as well
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 ) ;
END IF ;
2012-11-30 00:43:33 +04:00
END IF ;
END IF ;
RETURN TRUE ;
END IF ;
RETURN FALSE ;
END ;
$ $
LANGUAGE plpgsql ;