DECLARE
o TEXT;
BEGIN
- o := gettokenstring(transliteration(name));
+ o := public.gettokenstring(public.transliteration(name));
RETURN trim(substr(o,1,length(o)));
END;
$$
$$
LANGUAGE plpgsql;
+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;
+
CREATE OR REPLACE FUNCTION getorcreate_country(lookup_word TEXT, lookup_country_code varchar(2))
RETURNS INTEGER
AS $$
$$
LANGUAGE plpgsql;
-CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, lookup_class text, lookup_type text)
+CREATE OR REPLACE FUNCTION getorcreate_amenity(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text)
RETURNS INTEGER
AS $$
DECLARE
return_word_id INTEGER;
BEGIN
lookup_token := ' '||trim(lookup_word);
- SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type into return_word_id;
+ 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;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
- INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0);
+ INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0);
END IF;
RETURN return_word_id;
END;
$$
LANGUAGE plpgsql;
-CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, lookup_class text, lookup_type text, op text)
+CREATE OR REPLACE FUNCTION getorcreate_amenityoperator(lookup_word TEXT, normalized_word TEXT, lookup_class text, lookup_type text, op text)
RETURNS INTEGER
AS $$
DECLARE
return_word_id INTEGER;
BEGIN
lookup_token := ' '||trim(lookup_word);
- SELECT min(word_id) FROM word WHERE word_token = lookup_token and class=lookup_class and type = lookup_type and operator = op into return_word_id;
+ 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;
IF return_word_id IS NULL THEN
return_word_id := nextval('seq_word');
- INSERT INTO word VALUES (return_word_id, lookup_token, null, lookup_class, lookup_type, null, 0, op);
+ INSERT INTO word VALUES (return_word_id, lookup_token, normalized_word, lookup_class, lookup_type, null, 0, op);
END IF;
RETURN return_word_id;
END;
$$
LANGUAGE plpgsql IMMUTABLE;
+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;
+
+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;
+ postcode := upper(postcode);
+
+ 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;
+
+-- 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
+ outcode TEXT;
+ cnt INTEGER;
+BEGIN
+ -- 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
+ SELECT min(postcode), count(*) FROM
+ (SELECT postcode FROM location_postcode
+ WHERE ST_Contains(geom, location_postcode.geometry) LIMIT 2) sub
+ INTO outcode, cnt;
+
+ IF cnt = 1 THEN
+ RETURN outcode;
+ ELSE
+ RETURN null;
+ END IF;
+ END IF;
+
+ 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;
+
+ RETURN outcode;
+END;
+$$
+LANGUAGE plpgsql;
+
+
CREATE OR REPLACE FUNCTION create_country(src HSTORE, lookup_country_code varchar(2)) RETURNS VOID
AS $$
DECLARE
BEGIN
place_centre := ST_PointOnSurface(place);
---DEBUG: RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
+-- RAISE WARNING 'get_country_code, start: %', ST_AsText(place_centre);
-- Try for a OSM polygon
- FOR nearcountry IN select country_code from location_area_country where country_code is not null and not isguess and st_covers(geometry, place_centre) limit 1
+ FOR nearcountry IN select country_code from location_area_country where country_code is not null and st_covers(geometry, place_centre) limit 1
LOOP
RETURN nearcountry.country_code;
END LOOP;
---DEBUG: RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
+-- RAISE WARNING 'osm fallback: %', ST_AsText(place_centre);
-- Try for OSM fallback data
-- The order is to deal with places like HongKong that are 'states' within another polygon
RETURN nearcountry.country_code;
END LOOP;
---DEBUG: RAISE WARNING 'natural earth: %', ST_AsText(place_centre);
-
- -- Natural earth data
- FOR nearcountry IN select country_code from country_naturalearthdata where st_covers(geometry, place_centre) limit 1
- LOOP
- RETURN nearcountry.country_code;
- END LOOP;
-
---DEBUG: RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
+-- RAISE WARNING 'near osm fallback: %', ST_AsText(place_centre);
--
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
RETURN nearcountry.country_code;
END LOOP;
---DEBUG: RAISE WARNING 'near natural earth: %', ST_AsText(place_centre);
-
- -- Natural earth data
- FOR nearcountry IN select country_code from country_naturalearthdata where st_dwithin(geometry, place_centre, 0.5) limit 1
- LOOP
- RETURN nearcountry.country_code;
- END LOOP;
-
RETURN NULL;
END;
$$
keywords INTEGER[],
rank_search INTEGER,
rank_address INTEGER,
+ in_postcode TEXT,
geometry GEOMETRY
)
RETURNS BOOLEAN
AS $$
DECLARE
locationid INTEGER;
- isarea BOOLEAN;
centroid GEOMETRY;
diameter FLOAT;
x BOOLEAN;
splitGeom RECORD;
secgeo GEOMETRY;
+ postcode TEXT;
BEGIN
IF rank_search > 25 THEN
RAISE EXCEPTION 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
END IF;
--- RAISE WARNING 'Adding location with rank > 25 (% rank %)', place_id, rank_search;
-
x := deleteLocationArea(partition, place_id, rank_search);
- isarea := false;
- IF (ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_IsValid(geometry)) THEN
+ -- add postcode only if it contains a single entry, i.e. ignore postcode lists
+ postcode := NULL;
+ IF in_postcode is not null AND in_postcode not similar to '%(,|;)%' THEN
+ postcode := upper(trim (in_postcode));
+ END IF;
- isArea := true;
+ IF ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
centroid := ST_Centroid(geometry);
FOR secgeo IN select split_geometry(geometry) AS geom LOOP
- x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, centroid, secgeo);
+ x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, false, postcode, centroid, secgeo);
END LOOP;
ELSE
-- RAISE WARNING 'adding % diameter %', place_id, diameter;
secgeo := ST_Buffer(geometry, diameter);
- x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, ST_Centroid(geometry), secgeo);
+ x := insertLocationAreaLarge(partition, place_id, country_code, keywords, rank_search, rank_address, true, postcode, ST_Centroid(geometry), secgeo);
END IF;
$$
LANGUAGE plpgsql;
+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;
+
CREATE OR REPLACE FUNCTION osmline_insert() RETURNS TRIGGER
AS $$
i INTEGER;
postcode TEXT;
result BOOLEAN;
+ is_area BOOLEAN;
country_code VARCHAR(2);
default_language VARCHAR(10);
diameter FLOAT;
classtable TEXT;
- line RECORD;
+ classtype TEXT;
BEGIN
--DEBUG: RAISE WARNING '% % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
IF NEW.osm_type = 'X' THEN
-- E'X'ternal records should already be in the right format so do nothing
ELSE
- NEW.rank_search := 30;
- NEW.rank_address := NEW.rank_search;
-
- -- By doing in postgres we have the country available to us - currently only used for postcode
- IF NEW.class in ('place','boundary') AND NEW.type in ('postcode','postal_code') THEN
+ is_area := ST_GeometryType(NEW.geometry) IN ('ST_Polygon','ST_MultiPolygon');
- 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;
-
- NEW.postcode := NEW.address->'postcode';
- NEW.name := hstore('ref', NEW.postcode);
-
- IF NEW.country_code = 'gb' THEN
-
- IF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9][A-Z][A-Z])$' THEN
- NEW.rank_search := 25;
- NEW.rank_address := 5;
- ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])$' THEN
- NEW.rank_search := 23;
- NEW.rank_address := 5;
- ELSEIF NEW.postcode ~ '^([A-Z][A-Z]?[0-9][0-9A-Z])$' THEN
- NEW.rank_search := 21;
- NEW.rank_address := 5;
- END IF;
+ IF NEW.class in ('place','boundary')
+ AND NEW.type in ('postcode','postal_code') THEN
- ELSEIF NEW.country_code = 'sg' THEN
-
- IF NEW.postcode ~ '^([0-9]{6})$' THEN
- NEW.rank_search := 25;
- NEW.rank_address := 11;
- END IF;
-
- ELSEIF NEW.country_code = 'de' THEN
+ 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;
- IF NEW.postcode ~ '^([0-9]{5})$' THEN
- NEW.rank_search := 21;
- NEW.rank_address := 11;
- END IF;
+ NEW.name := hstore('ref', NEW.address->'postcode');
- ELSE
- -- Guess at the postcode format and coverage (!)
- IF upper(NEW.postcode) ~ '^[A-Z0-9]{1,5}$' THEN -- Probably too short to be very local
- NEW.rank_search := 21;
- NEW.rank_address := 11;
- ELSE
- -- Does it look splitable into and area and local code?
- postcode := substring(upper(NEW.postcode) from '^([- :A-Z0-9]+)([- :][A-Z0-9]+)$');
-
- IF postcode IS NOT NULL THEN
- NEW.rank_search := 25;
- NEW.rank_address := 11;
- ELSEIF NEW.postcode ~ '^[- :A-Z0-9]{6,}$' THEN
- NEW.rank_search := 21;
- NEW.rank_address := 11;
- END IF;
- END IF;
- END IF;
+ SELECT * FROM get_postcode_rank(NEW.country_code, NEW.address->'postcode')
+ INTO NEW.rank_search, NEW.rank_address;
- ELSEIF NEW.class = 'place' THEN
- IF NEW.type in ('continent') THEN
- NEW.rank_search := 2;
- NEW.rank_address := NEW.rank_search;
- NEW.country_code := NULL;
- ELSEIF NEW.type in ('sea') THEN
- NEW.rank_search := 2;
- NEW.rank_address := 0;
- NEW.country_code := NULL;
- ELSEIF NEW.type in ('country') THEN
- NEW.rank_search := 4;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('state') THEN
- NEW.rank_search := 8;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('region') THEN
- NEW.rank_search := 18; -- dropped from previous value of 10
- NEW.rank_address := 0; -- So badly miss-used that better to just drop it!
- ELSEIF NEW.type in ('county') THEN
- NEW.rank_search := 12;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('city') THEN
- NEW.rank_search := 16;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('island') THEN
- NEW.rank_search := 17;
- NEW.rank_address := 0;
- ELSEIF NEW.type in ('town') THEN
- NEW.rank_search := 18;
- NEW.rank_address := 16;
- ELSEIF NEW.type in ('village','hamlet','municipality','district','unincorporated_area','borough') THEN
- NEW.rank_search := 19;
- NEW.rank_address := 16;
- ELSEIF NEW.type in ('suburb','croft','subdivision','isolated_dwelling') THEN
- NEW.rank_search := 20;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('farm','locality','islet','mountain_pass') THEN
- NEW.rank_search := 20;
- NEW.rank_address := 0;
- -- Irish townlands, tagged as place=locality and locality=townland
- IF (NEW.extratags -> 'locality') = 'townland' THEN
- NEW.rank_address := 20;
- END IF;
- ELSEIF NEW.type in ('neighbourhood') THEN
- NEW.rank_search := 22;
- NEW.rank_address := 22;
- ELSEIF NEW.type in ('house','building') THEN
- NEW.rank_search := 30;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.type in ('houses') THEN
- -- can't guarantee all required nodes loaded yet due to caching in osm2pgsql
- NEW.rank_search := 28;
- NEW.rank_address := 0;
+ IF NOT is_area THEN
+ NEW.rank_address := 0;
END IF;
-
- ELSEIF NEW.class = 'boundary' THEN
- IF ST_GeometryType(NEW.geometry) NOT IN ('ST_Polygon','ST_MultiPolygon') THEN
--- RAISE WARNING 'invalid boundary %',NEW.osm_id;
+ ELSEIF NEW.class = 'boundary' AND NOT is_area THEN
return NULL;
- END IF;
- NEW.rank_search := NEW.admin_level * 2;
- IF NEW.type = 'administrative' THEN
- NEW.rank_address := NEW.rank_search;
+ ELSEIF NEW.class = 'boundary' AND NEW.type = 'administrative'
+ AND NEW.admin_level <= 4 AND NEW.osm_type = 'W' THEN
+ return NULL;
+ 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;
ELSE
- NEW.rank_address := 0;
+ classtype = NEW.type;
END IF;
- ELSEIF NEW.class = 'landuse' AND ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') THEN
- NEW.rank_search := 22;
- IF NEW.type in ('residential', 'farm', 'farmyard', 'industrial', 'commercial', 'allotments', 'retail') THEN
- NEW.rank_address := NEW.rank_search;
- ELSE
- NEW.rank_address := 0;
+ 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;
END IF;
- ELSEIF NEW.class = 'natural' and NEW.type in ('peak','volcano','mountain_range') THEN
- NEW.rank_search := 18;
- NEW.rank_address := 0;
- ELSEIF NEW.class = 'natural' and NEW.type = 'sea' THEN
- NEW.rank_search := 4;
- NEW.rank_address := NEW.rank_search;
- -- any feature more than 5 square miles is probably worth indexing
- ELSEIF ST_GeometryType(NEW.geometry) in ('ST_Polygon','ST_MultiPolygon') AND ST_Area(NEW.geometry) > 0.1 THEN
- NEW.rank_search := 22;
- NEW.rank_address := 0;
- ELSEIF NEW.class = 'railway' AND NEW.type in ('rail') THEN
- RETURN NULL;
- ELSEIF NEW.class = 'waterway' THEN
- IF NEW.osm_type = 'R' THEN
- NEW.rank_search := 16;
- ELSE
- NEW.rank_search := 17;
+
+ IF NEW.rank_address is NULL THEN
+ NEW.rank_address := 30;
END IF;
- NEW.rank_address := 0;
- ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' AND NEW.type in ('service','cycleway','path','footway','steps','bridleway','motorway_link','primary_link','trunk_link','secondary_link','tertiary_link') THEN
- NEW.rank_search := 27;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.class = 'highway' AND NEW.osm_type != 'N' THEN
- NEW.rank_search := 26;
- NEW.rank_address := NEW.rank_search;
- ELSEIF NEW.class = 'mountain_pass' THEN
- NEW.rank_search := 20;
- NEW.rank_address := 0;
END IF;
- END IF;
-
- IF NEW.rank_search > 30 THEN
- NEW.rank_search := 30;
- END IF;
+ -- some postcorrections
+ IF NEW.class = 'waterway' AND NEW.osm_type = 'R' THEN
+ -- Slightly promote waterway relations so that they are processed
+ -- before their members.
+ NEW.rank_search := NEW.rank_search - 1;
+ END IF;
- IF NEW.rank_address > 30 THEN
- NEW.rank_address := 30;
- END IF;
+ IF (NEW.extratags -> 'capital') = 'yes' THEN
+ NEW.rank_search := NEW.rank_search - 1;
+ END IF;
- IF (NEW.extratags -> 'capital') = 'yes' THEN
- NEW.rank_search := NEW.rank_search - 1;
END IF;
-- a country code make no sense below rank 4 (country)
NEW.country_code := NULL;
END IF;
--- Block import below rank 22
--- IF NEW.rank_search > 22 THEN
--- RETURN NULL;
--- END IF;
-
--DEBUG: RAISE WARNING 'placex_insert:END: % % % %',NEW.osm_type,NEW.osm_id,NEW.class,NEW.type;
RETURN NEW; -- %DIFFUPDATES% The following is not needed until doing diff updates, and slows the main index process down
- IF NEW.rank_address > 0 THEN
+ 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
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
linegeo GEOMETRY;
splitline GEOMETRY;
sectiongeo GEOMETRY;
+ interpol_postcode TEXT;
postcode TEXT;
- seg_postcode TEXT;
BEGIN
-- deferred delete
IF OLD.indexed_status = 100 THEN
NEW.address->'place',
NEW.partition, place_centroid, NEW.linegeo);
-
- IF NEW.address is not NULL and NEW.address ? 'postcode' THEN
- NEW.postcode = NEW.address->'postcode';
+ 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;
END IF;
-- if the line was newly inserted, split the line as necessary
linegeo := NEW.linegeo;
startnumber := NULL;
- postcode := NEW.postcode;
FOR nodeidpos in 1..array_upper(waynodes, 1) LOOP
sectiongeo := ST_Reverse(sectiongeo);
END IF;
- seg_postcode := coalesce(postcode,
- prevnode.address->'postcode',
- nextnode.address->'postcode');
+ -- 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;
IF NEW.startnumber IS NULL THEN
NEW.startnumber := startnumber;
NEW.endnumber := endnumber;
NEW.linegeo := sectiongeo;
- NEW.postcode := seg_postcode;
+ NEW.postcode := upper(trim(postcode));
ELSE
insert into location_property_osmline
(linegeo, partition, osm_id, parent_place_id,
geometry_sector, indexed_status)
values (sectiongeo, NEW.partition, NEW.osm_id, NEW.parent_place_id,
startnumber, endnumber, NEW.interpolationtype,
- NEW.address, seg_postcode,
+ NEW.address, postcode,
NEW.country_code, NEW.geometry_sector, 0);
END IF;
END IF;
$$
LANGUAGE plpgsql;
+-- 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();
+
+ 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;
CREATE OR REPLACE FUNCTION placex_update() RETURNS
TRIGGER
DECLARE
place_centroid GEOMETRY;
+ near_centroid GEOMETRY;
search_maxdistance FLOAT[];
search_mindistance FLOAT[];
relation_members TEXT[];
relMember RECORD;
linkedplacex RECORD;
+ addr_item RECORD;
search_diameter FLOAT;
search_prevdiameter FLOAT;
search_maxrank INTEGER;
BEGIN
-- deferred delete
IF OLD.indexed_status = 100 THEN
- --DEBUG: RAISE WARNING 'placex_update_delete % %',NEW.osm_type,NEW.osm_id;
+ --DEBUG: RAISE WARNING 'placex_update delete % %',NEW.osm_type,NEW.osm_id;
delete from placex where place_id = OLD.place_id;
RETURN NULL;
END IF;
RETURN NEW;
END IF;
- --DEBUG: RAISE WARNING 'placex_update % %',NEW.osm_type,NEW.osm_id;
-
---RAISE WARNING '%',NEW.place_id;
---RAISE WARNING '%', NEW;
-
- IF NEW.class = 'place' AND NEW.type = 'postcodearea' THEN
- -- Silently do nothing
- RETURN NEW;
- END IF;
+ --DEBUG: RAISE WARNING 'placex_update % % (%)',NEW.osm_type,NEW.osm_id,NEW.place_id;
NEW.indexed_date = now();
+ IF NOT %REVERSE-ONLY% THEN
+ DELETE from search_name WHERE place_id = NEW.place_id;
+ END IF;
result := deleteSearchName(NEW.partition, NEW.place_id);
DELETE FROM place_addressline WHERE place_id = NEW.place_id;
result := deleteRoad(NEW.partition, NEW.place_id);
-- update not necessary for osmline, cause linked_place_id does not exist
IF NEW.linked_place_id is not null THEN
+ --DEBUG: RAISE WARNING 'place already linked to %', NEW.linked_place_id;
RETURN NEW;
END IF;
+ --DEBUG: RAISE WARNING 'Copy over address tags';
+ -- housenumber is a computed field, so start with an empty value
+ NEW.housenumber := NULL;
IF NEW.address is not NULL THEN
IF NEW.address ? 'conscriptionnumber' THEN
i := getorcreate_housenumber_id(make_standard_name(NEW.address->'conscriptionnumber'));
i := getorcreate_housenumber_id(make_standard_name(NEW.housenumber));
END IF;
- addr_street = NEW.address->'street';
- addr_place = NEW.address->'place';
+ addr_street := NEW.address->'street';
+ addr_place := NEW.address->'place';
- NEW.postcode = NEW.address->'postcode';
+ IF NEW.address ? 'postcode' and NEW.address->'postcode' not similar to '%(,|;)%' THEN
+ i := getorcreate_postcode_id(NEW.address->'postcode');
+ END IF;
END IF;
-- Speed up searches - just use the centroid of the feature
-- cheaper but less acurate
place_centroid := ST_PointOnSurface(NEW.geometry);
+ -- For searching near features rather use the centroid
+ near_centroid := ST_Envelope(NEW.geometry);
NEW.centroid := null;
+ NEW.postcode := null;
+ --DEBUG: RAISE WARNING 'Computing preliminary centroid at %',ST_AsText(place_centroid);
-- recalculate country and partition
IF NEW.rank_search = 4 AND NEW.address is not NULL AND NEW.address ? 'country' THEN
END IF;
NEW.partition := get_partition(NEW.country_code);
END IF;
+ --DEBUG: RAISE WARNING 'Country updated: "%"', NEW.country_code;
-- 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
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
- --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation.members[i];
+ --DEBUG: RAISE WARNING 'waterway parent %, child %/%', NEW.osm_id, i, relation_members[i];
FOR linked_node_id IN SELECT place_id FROM placex
WHERE osm_type = 'W' and osm_id = substring(relation_members[i],2,200)::bigint
- and class = NEW.class and type = NEW.type
+ and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
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 IF;
END LOOP;
END LOOP;
+ --DEBUG: RAISE WARNING 'Waterway processed';
END IF;
- -- Adding ourselves to the list simplifies address calculations later
- INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
- VALUES (NEW.place_id, NEW.place_id, true, true, 0, NEW.rank_address);
-
-- What level are we searching from
search_maxrank := NEW.rank_search;
END IF;
END IF;
END IF;
+ --DEBUG: RAISE WARNING 'Local names updated';
-- Initialise the name vector using our name
name_vector := make_keywords(NEW.name);
END LOOP;
NEW.importance := null;
- select language||':'||title,importance from get_wikipedia_match(NEW.extratags, NEW.country_code) INTO NEW.wikipedia,NEW.importance;
- IF NEW.importance IS NULL THEN
- select language||':'||title,importance from wikipedia_article where osm_type = NEW.osm_type and osm_id = NEW.osm_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
- END IF;
+ SELECT wikipedia, importance
+ FROM compute_importance(NEW.extratags, NEW.country_code, NEW.osm_type, NEW.osm_id)
+ INTO NEW.wikipedia,NEW.importance;
---RAISE WARNING 'before low level% %', NEW.place_id, NEW.rank_search;
+--DEBUG: RAISE WARNING 'Importance computed from wikipedia: %', NEW.importance;
-- ---------------------------------------------------------------------------
-- 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
---RAISE WARNING 'finding street for %', NEW;
+ --DEBUG: RAISE WARNING 'finding street for % %', NEW.osm_type, NEW.osm_id;
-- We won't get a better centroid, besides these places are too small to care
NEW.centroid := place_centroid;
-- see if we can get it from a surrounding building
IF NEW.osm_type = 'N' AND addr_street IS NULL AND addr_place IS NULL
AND NEW.housenumber IS NULL THEN
- FOR location IN select * from placex where ST_Covers(geometry, place_centroid)
+ FOR location IN select address from placex where ST_Covers(geometry, place_centroid)
and address is not null
and (address ? 'housenumber' or address ? 'street' or address ? 'place')
and rank_search > 28 AND ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon')
NEW.housenumber := location.address->'housenumber';
addr_street := location.address->'street';
addr_place := location.address->'place';
+ --DEBUG: RAISE WARNING 'Found surrounding building % %', location.osm_type, location.osm_id;
END LOOP;
END IF;
END LOOP;
END IF;
END LOOP;
-
+ --DEBUG: RAISE WARNING 'Checked for street relation (%)', NEW.parent_place_id;
-- Note that addr:street links can only be indexed once the street itself is indexed
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));
IF address_street_word_ids IS NOT NULL THEN
- FOR location IN SELECT * from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
- NEW.parent_place_id := location.place_id;
- END LOOP;
+ SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
END IF;
END IF;
+ --DEBUG: RAISE WARNING 'Checked for addr:street (%)', NEW.parent_place_id;
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));
IF address_street_word_ids IS NOT NULL THEN
- FOR location IN SELECT * from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
- NEW.parent_place_id := location.place_id;
- END LOOP;
+ SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
END IF;
END IF;
+ --DEBUG: RAISE WARNING 'Checked for addr:place (%)', NEW.parent_place_id;
-- Is this node part of an interpolation?
IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
- FOR location IN
- 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
- LOOP
- NEW.parent_place_id := location.parent_place_id;
- END LOOP;
+ 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;
END IF;
+ --DEBUG: RAISE WARNING 'Checked for interpolation (%)', NEW.parent_place_id;
-- Is this node part of a way?
IF NEW.parent_place_id IS NULL AND NEW.osm_type = 'N' THEN
- FOR location IN select p.place_id, p.osm_id, p.parent_place_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)
+ 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)
LOOP
+ --DEBUG: RAISE WARNING 'Node is part of way % ', location.osm_id;
-- Way IS a road then we are on it - that must be our road
- IF location.rank_search < 28 AND NEW.parent_place_id IS NULL THEN
+ IF location.rank_search < 28 THEN
--RAISE WARNING 'node in way that is a street %',location;
NEW.parent_place_id := location.place_id;
+ EXIT;
END IF;
+ --DEBUG: RAISE WARNING 'Checked if way is street (%)', NEW.parent_place_id;
-- If the way mentions a street or place address, try that for parenting.
- IF NEW.parent_place_id IS NULL AND 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
- FOR linkedplacex IN SELECT place_id from getNearestNamedRoadFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
- NEW.parent_place_id := linkedplacex.place_id;
- END LOOP;
+ 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
+ SELECT place_id from getNearestNamedRoadFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
+ EXIT WHEN NEW.parent_place_id is not NULL;
+ END IF;
END IF;
- END IF;
+ --DEBUG: RAISE WARNING 'Checked for addr:street in way (%)', NEW.parent_place_id;
- IF NEW.parent_place_id IS NULL AND 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
- FOR linkedplacex IN SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, place_centroid, address_street_word_ids) LOOP
- NEW.parent_place_id := linkedplacex.place_id;
- END LOOP;
+ 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
+ SELECT place_id from getNearestNamedPlaceFeature(NEW.partition, near_centroid, address_street_word_ids) INTO NEW.parent_place_id;
+ EXIT WHEN NEW.parent_place_id is not NULL;
+ END IF;
END IF;
+ --DEBUG: RAISE WARNING 'Checked for addr:place in way (%)', NEW.parent_place_id;
END IF;
-- Is the WAY part of a relation
- IF NEW.parent_place_id IS NULL THEN
- 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;
- END IF;
- END LOOP;
+ 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;
END IF;
END LOOP;
- END IF;
+ END IF;
+ END LOOP;
+ EXIT WHEN NEW.parent_place_id is not null;
+ --DEBUG: RAISE WARNING 'Checked for street relation in way (%)', NEW.parent_place_id;
END LOOP;
-
END IF;
---RAISE WARNING 'x4 %',NEW.parent_place_id;
-- Still nothing, just use the nearest road
IF NEW.parent_place_id IS NULL THEN
- FOR location IN SELECT place_id FROM getNearestRoadFeature(NEW.partition, place_centroid) LOOP
- NEW.parent_place_id := location.place_id;
- END LOOP;
+ SELECT place_id FROM getNearestRoadFeature(NEW.partition, near_centroid) INTO NEW.parent_place_id;
END IF;
+ --DEBUG: RAISE WARNING 'Checked for nearest way (%)', NEW.parent_place_id;
---return NEW;
---RAISE WARNING 'x6 %',NEW.parent_place_id;
-- If we didn't find any road fallback to standard method
IF NEW.parent_place_id IS NOT NULL THEN
-- Get the details of the parent road
- select * from search_name where place_id = NEW.parent_place_id INTO location;
+ SELECT p.country_code, p.postcode FROM placex p
+ WHERE p.place_id = NEW.parent_place_id INTO location;
+
NEW.country_code := location.country_code;
+ --DEBUG: RAISE WARNING 'Got parent details from search name';
- -- Merge the postcode into the parent's address if necessary
- IF NEW.postcode IS NOT NULL THEN
- isin_tokens := '{}'::int[];
- address_street_word_id := getorcreate_word_id(make_standard_name(NEW.postcode));
- IF address_street_word_id is not null
- and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
- isin_tokens := isin_tokens || address_street_word_id;
- END IF;
- address_street_word_id := getorcreate_name_id(make_standard_name(NEW.postcode));
- IF address_street_word_id is not null
- and not ARRAY[address_street_word_id] <@ location.nameaddress_vector THEN
- isin_tokens := isin_tokens || address_street_word_id;
- END IF;
- IF isin_tokens != '{}'::int[] THEN
- UPDATE search_name
- SET nameaddress_vector = search_name.nameaddress_vector || isin_tokens
- WHERE place_id = NEW.parent_place_id;
- END IF;
+ -- determine postcode
+ IF NEW.rank_search > 4 THEN
+ IF NEW.address is not null AND NEW.address ? 'postcode' THEN
+ NEW.postcode = upper(trim(NEW.address->'postcode'));
+ ELSE
+ NEW.postcode := location.postcode;
+ END IF;
+ IF NEW.postcode is null THEN
+ NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
+ END IF;
END IF;
---RAISE WARNING '%', NEW.name;
-- If there is no name it isn't searchable, don't bother to create a search record
IF NEW.name is NULL THEN
+ --DEBUG: RAISE WARNING 'Not a searchable place % %', NEW.osm_type, NEW.osm_id;
return NEW;
END IF;
- -- Merge address from parent
- nameaddress_vector := array_merge(nameaddress_vector, location.nameaddress_vector);
- nameaddress_vector := array_merge(nameaddress_vector, location.name_vector);
-
-- 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
- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
+ 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);
+ --DEBUG: RAISE WARNING 'Place added to location table';
END IF;
- result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
+ 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;
return NEW;
END IF;
END IF;
--- RAISE WARNING ' INDEXING Started:';
--- RAISE WARNING ' INDEXING: %',NEW;
-
-- ---------------------------------------------------------------------------
-- Full indexing
+ --DEBUG: RAISE WARNING 'Using full index mode for % %', NEW.osm_type, NEW.osm_id;
IF NEW.osm_type = 'R' AND NEW.rank_search < 26 THEN
-- see if we have any special relation members
select members from planet_osm_rels where id = NEW.osm_id INTO relation_members;
+ --DEBUG: RAISE WARNING 'Got relation members';
--- RAISE WARNING 'get_osm_rel_members, label';
IF relation_members IS NOT NULL THEN
FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['label']) as member LOOP
+ --DEBUG: RAISE WARNING 'Found label member %', relMember.member;
FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
- and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
+ and osm_id = substring(relMember.member,2,10000)::bigint
+ and class = 'place' order by rank_search desc limit 1 LOOP
-- If we don't already have one use this as the centre point of the geometry
IF NEW.centroid IS NULL THEN
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
- -- keep a note of the node id in case we need it for wikipedia in a bit
- linked_node_id := linkedPlacex.osm_id;
- select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
+ select wikipedia, importance
+ FROM compute_importance(linkedPlacex.extratags, NEW.country_code,
+ 'N', linkedPlacex.osm_id)
+ INTO linked_wikipedia,linked_importance;
+ --DEBUG: RAISE WARNING 'Linked label member';
END LOOP;
END LOOP;
IF NEW.centroid IS NULL THEN
FOR relMember IN select get_osm_rel_members(relation_members,ARRAY['admin_center','admin_centre']) as member LOOP
+ --DEBUG: RAISE WARNING 'Found admin_center member %', relMember.member;
FOR linkedPlacex IN select * from placex where osm_type = upper(substring(relMember.member,1,1))::char(1)
- and osm_id = substring(relMember.member,2,10000)::bigint order by rank_search desc limit 1 LOOP
+ and osm_id = substring(relMember.member,2,10000)::bigint
+ and class = 'place' order by rank_search desc limit 1 LOOP
-- 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
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
- -- keep a note of the node id in case we need it for wikipedia in a bit
- linked_node_id := linkedPlacex.osm_id;
- select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
+ select wikipedia, importance
+ FROM compute_importance(linkedPlacex.extratags, NEW.country_code,
+ 'N', linkedPlacex.osm_id)
+ INTO linked_wikipedia,linked_importance;
+ --DEBUG: RAISE WARNING 'Linked admin_center';
END IF;
END LOOP;
-- 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
+ --DEBUG: RAISE WARNING 'Looking for nodes with matching names';
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.osm_type = 'N'::char(1) AND placex.rank_search < 26
AND st_covers(NEW.geometry, placex.geometry)
LOOP
-
+ --DEBUG: RAISE WARNING 'Found matching place node %', linkedPlacex.osm_id;
-- 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));
-- mark the linked place (excludes from search results)
UPDATE placex set linked_place_id = NEW.place_id where place_id = linkedPlacex.place_id;
- -- keep a note of the node id in case we need it for wikipedia in a bit
- linked_node_id := linkedPlacex.osm_id;
- select language||':'||title,importance from get_wikipedia_match(linkedPlacex.extratags, NEW.country_code) INTO linked_wikipedia,linked_importance;
+ select wikipedia, importance
+ FROM compute_importance(linkedPlacex.extratags, NEW.country_code,
+ 'N', linkedPlacex.osm_id)
+ INTO linked_wikipedia,linked_importance;
+ --DEBUG: RAISE WARNING 'Linked named place';
END LOOP;
END IF;
END IF;
END IF;
END IF;
+ --DEBUG: RAISE WARNING 'Names updated from linked places';
END IF;
-- Use the maximum importance if a one could be computed from the linked object.
(NEW.importance is null or NEW.importance < linked_importance) THEN
NEW.importance = linked_importance;
END IF;
-
- -- Still null? how about looking it up by the node id
- IF NEW.importance IS NULL THEN
- select language||':'||title,importance from wikipedia_article where osm_type = 'N'::char(1) and osm_id = linked_node_id order by importance desc limit 1 INTO NEW.wikipedia,NEW.importance;
- END IF;
-
END IF;
-- make sure all names are in the word table
- IF NEW.admin_level = 2 AND NEW.class = 'boundary' AND NEW.type = 'administrative' AND NEW.country_code IS NOT NULL THEN
+ 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
perform create_country(NEW.name, lower(NEW.country_code));
+ --DEBUG: RAISE WARNING 'Country names updated';
END IF;
NEW.parent_place_id = 0;
parent_place_id_rank = 0;
- -- convert isin to array of tokenids
+ -- convert address store to array of tokenids
+ --DEBUG: RAISE WARNING 'Starting address search';
isin_tokens := '{}'::int[];
IF NEW.address IS NOT NULL THEN
- isin := avals(NEW.address);
- 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]));
+ 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));
IF address_street_word_id IS NOT NULL AND NOT(ARRAY[address_street_word_id] <@ isin_tokens) THEN
- nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
isin_tokens := isin_tokens || address_street_word_id;
END IF;
-
- -- merge word into address vector
- 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;
- END LOOP;
- END IF;
- END IF;
- IF NEW.postcode IS NOT NULL THEN
- isin := regexp_split_to_array(NEW.postcode, E'[;,]');
- 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
- nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
- isin_tokens := isin_tokens || address_street_word_id;
+ 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;
END IF;
+ END IF;
+ IF addr_item.key = 'is_in' THEN
+ -- is_in items need splitting
+ isin := regexp_split_to_array(addr_item.value, E'[;,]');
+ 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 into address vector
- 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]);
+ -- merge word into address vector
+ 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;
+ END IF;
+ END LOOP;
END IF;
- END LOOP;
- END IF;
- END IF;
-
- -- %NOTIGERDATA% IF 0 THEN
- -- for the USA we have an additional address table. Merge in zip codes from there too
- IF NEW.rank_search = 26 AND NEW.country_code = 'us' THEN
- FOR location IN SELECT distinct postcode from location_property_tiger where parent_place_id = NEW.place_id LOOP
- address_street_word_id := get_name_id(make_standard_name(location.postcode));
- nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
- isin_tokens := isin_tokens || address_street_word_id;
-
- -- also merge in the single word version
- address_street_word_id := get_word_id(make_standard_name(location.postcode));
- nameaddress_vector := array_merge(nameaddress_vector, ARRAY[address_street_word_id]);
+ END IF;
END LOOP;
END IF;
- -- %NOTIGERDATA% END IF;
+ IF NOT %REVERSE-ONLY% THEN
+ nameaddress_vector := array_merge(nameaddress_vector, isin_tokens);
+ END IF;
-- RAISE WARNING 'ISIN: %', isin_tokens;
location_parent := NULL;
-- added ourself as address already
address_havelevel[NEW.rank_address] := true;
- -- RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
+ --DEBUG: RAISE WARNING ' getNearFeatures(%,''%'',%,''%'')',NEW.partition, place_centroid, search_maxrank, isin_tokens;
FOR location IN
SELECT * from getNearFeatures(NEW.partition,
CASE WHEN NEW.rank_search >= 26
ELSE place_centroid END,
search_maxrank, isin_tokens)
LOOP
-
---RAISE WARNING ' AREA: %',location;
-
IF location.rank_address != location_rank_search THEN
location_rank_search := location.rank_address;
IF location.isguess THEN
-- RAISE WARNING '% isaddress: %', location.place_id, location_isaddress;
-- Add it to the list of search terms
- IF location.rank_search > 4 THEN
+ IF NOT %REVERSE-ONLY% THEN
nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
END IF;
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);
IF location_isaddress THEN
+ -- 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;
address_havelevel[location.rank_address] := true;
IF NOT location.isguess THEN
END IF;
---RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
+ --DEBUG: RAISE WARNING ' Terms: (%) %',location, nameaddress_vector;
END IF;
END LOOP;
+ --DEBUG: RAISE WARNING 'address computed';
- -- try using the isin value to find parent places
- IF array_upper(isin_tokens, 1) IS NOT NULL THEN
- FOR i IN 1..array_upper(isin_tokens, 1) LOOP
---RAISE WARNING ' getNearestNamedFeature: % % % %',NEW.partition, place_centroid, search_maxrank, isin_tokens[i];
- IF NOT ARRAY[isin_tokens[i]] <@ nameaddress_vector THEN
-
- FOR location IN SELECT * from getNearestNamedFeature(NEW.partition, place_centroid, search_maxrank, isin_tokens[i]) LOOP
-
---RAISE WARNING ' ISIN: %',location;
-
- IF location.rank_search > 4 THEN
- nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
- INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
- VALUES (NEW.place_id, location.place_id, false, NOT address_havelevel[location.rank_address], location.distance, location.rank_address);
- address_havelevel[location.rank_address] := true;
-
- 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;
- END IF;
- END LOOP;
-
- END IF;
-
- END LOOP;
+ IF NEW.address is not null AND NEW.address ? 'postcode'
+ AND NEW.address->'postcode' not similar to '%(,|;)%' THEN
+ NEW.postcode := upper(trim(NEW.address->'postcode'));
END IF;
- -- for long ways we should add search terms for the entire length
- IF st_length(NEW.geometry) > 0.05 THEN
-
- location_rank_search := 0;
- location_distance := 0;
-
- FOR location IN SELECT * from getNearFeatures(NEW.partition, NEW.geometry, search_maxrank, isin_tokens) LOOP
-
- IF location.rank_address != location_rank_search THEN
- location_rank_search := location.rank_address;
- location_distance := location.distance * 1.5;
- END IF;
-
- IF location.rank_search > 4 AND location.distance < location_distance THEN
-
- -- Add it to the list of search terms
- nameaddress_vector := array_merge(nameaddress_vector, location.keywords::integer[]);
- INSERT INTO place_addressline (place_id, address_place_id, fromarea, isaddress, distance, cached_rank_address)
- VALUES (NEW.place_id, location.place_id, true, false, location.distance, location.rank_address);
-
- END IF;
-
- END LOOP;
-
+ IF NEW.postcode is null AND NEW.rank_search > 8 THEN
+ NEW.postcode := get_nearest_postcode(NEW.country_code, NEW.geometry);
END IF;
-- if we have a name add this to the name search table
IF NEW.name IS NOT NULL THEN
IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
- result := add_location(NEW.place_id, NEW.country_code, NEW.partition, name_vector, NEW.rank_search, NEW.rank_address, NEW.geometry);
+ 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);
+ --DEBUG: RAISE WARNING 'added to location (full)';
END IF;
IF NEW.rank_search between 26 and 27 and NEW.class = 'highway' THEN
result := insertLocationRoad(NEW.partition, NEW.place_id, NEW.country_code, NEW.geometry);
+ --DEBUG: RAISE WARNING 'insert into road location table (full)';
END IF;
- result := insertSearchName(NEW.partition, NEW.place_id, NEW.country_code, name_vector, nameaddress_vector, NEW.rank_search, NEW.rank_address, NEW.importance, place_centroid, NEW.geometry);
+ 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;
END IF;
IF NEW.centroid IS NULL THEN
NEW.centroid := place_centroid;
END IF;
-
+
+ --DEBUG: RAISE WARNING 'place update % % finsihed.', NEW.osm_type, NEW.osm_id;
+
RETURN NEW;
END;
$$
--DEBUG: RAISE WARNING 'placex_delete:09 % %',OLD.osm_type,OLD.osm_id;
IF OLD.name is not null THEN
+ IF NOT %REVERSE-ONLY% THEN
+ DELETE from search_name WHERE place_id = OLD.place_id;
+ END IF;
b := deleteSearchName(OLD.partition, OLD.place_id);
END IF;
-- To paraphrase, if there isn't an existing item, OR if the admin level has changed
IF existingplacex.osm_type IS NULL OR
- (coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.class = 'boundary' AND existingplacex.type = 'administrative')
+ (existingplacex.class = 'boundary' AND
+ ((coalesce(existingplacex.admin_level, 15) != coalesce(NEW.admin_level, 15) AND existingplacex.type = 'administrative') OR
+ (existingplacex.type != NEW.type)))
THEN
IF existingplacex.osm_type IS NOT NULL THEN
NEW.name := hstore('ref', NEW.address->'postcode');
END IF;
+ 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;
+
update placex set
name = NEW.name,
address = NEW.address,
indexed_status = 2,
geometry = NEW.geometry
where place_id = existingplacex.place_id;
-
-- 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)
- IF NEW.osm_type='N' and NEW.class='place' and NEW.type='house' THEN
- -- Is this node part of an interpolation line? search for it in location_property_osmline and mark the interpolation line for reparenting
- update location_property_osmline p set indexed_status = 2 from planet_osm_ways w where p.linegeo && NEW.geometry and p.osm_id = w.id and NEW.osm_id = any(w.nodes);
+ 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);
+ END IF;
+
+ -- 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;
END IF;
$$
LANGUAGE plpgsql IMMUTABLE;
-
-CREATE OR REPLACE FUNCTION get_address_postcode(for_place_id BIGINT) RETURNS TEXT
- AS $$
-DECLARE
- result TEXT[];
- search TEXT[];
- for_postcode TEXT;
- found INTEGER;
- location RECORD;
-BEGIN
-
- found := 1000;
- search := ARRAY['ref'];
- result := '{}';
-
- select postcode from placex where place_id = for_place_id limit 1 into for_postcode;
-
- FOR location IN
- select rank_address,name,distance,length(name::text) as namelength
- from place_addressline join placex on (address_place_id = placex.place_id)
- where place_addressline.place_id = for_place_id and rank_address in (5,11)
- order by rank_address desc,rank_search desc,fromarea desc,distance asc,namelength desc
- LOOP
- IF array_upper(search, 1) IS NOT NULL AND array_upper(location.name, 1) IS NOT NULL THEN
- FOR j IN 1..array_upper(search, 1) LOOP
- FOR k IN 1..array_upper(location.name, 1) LOOP
- IF (found > location.rank_address AND location.name[k].key = search[j] AND location.name[k].value != '') AND NOT result @> ARRAY[trim(location.name[k].value)] AND (for_postcode IS NULL OR location.name[k].value ilike for_postcode||'%') THEN
- result[(100 - location.rank_address)] := trim(location.name[k].value);
- found := location.rank_address;
- END IF;
- END LOOP;
- END LOOP;
- END IF;
- END LOOP;
-
- RETURN array_to_string(result,', ');
-END;
-$$
-LANGUAGE plpgsql;
-
--housenumber only needed for tiger data
CREATE OR REPLACE FUNCTION get_address_by_language(for_place_id BIGINT, housenumber INTEGER, languagepref TEXT[]) RETURNS TEXT
AS $$
distance FLOAT
);
+-- Compute the list of address parts for the given place.
+--
+-- If in_housenumber is greator or equal 0, look for an interpolation.
CREATE OR REPLACE FUNCTION get_addressdata(in_place_id BIGINT, in_housenumber INTEGER) RETURNS setof addressline
AS $$
DECLARE
searchhousename HSTORE;
searchrankaddress INTEGER;
searchpostcode TEXT;
+ postcode_isaddress BOOL;
searchclass TEXT;
searchtype TEXT;
countryname HSTORE;
- hadcountry BOOLEAN;
BEGIN
+ -- 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.
+
+ postcode_isaddress := true;
+
-- first query osmline (interpolation lines)
- select parent_place_id, country_code, 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, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
- IF for_place_id IS NOT NULL THEN
- searchhousenumber = in_housenumber::text;
+ 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;
END IF;
--then query tiger data
-- %NOTIGERDATA% IF 0 THEN
- IF for_place_id IS NULL THEN
- select parent_place_id,'us', 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, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
- IF for_place_id IS NOT NULL THEN
- searchhousenumber = in_housenumber::text;
- END IF;
+ 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;
END IF;
-- %NOTIGERDATA% END IF;
-- %NOAUXDATA% IF 0 THEN
IF for_place_id IS NULL THEN
- select parent_place_id,'us', housenumber, 30, postcode, null, 'place', 'house' from location_property_aux
- WHERE place_id = in_place_id
- INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode, searchhousename, searchclass, searchtype;
+ SELECT parent_place_id, 'us', housenumber, 30, postcode, null, 'place', 'house'
+ FROM location_property_aux
+ WHERE place_id = in_place_id
+ INTO for_place_id,searchcountrycode, searchhousenumber, searchrankaddress,
+ searchpostcode, searchhousename, searchclass, searchtype;
END IF;
-- %NOAUXDATA% END IF;
+ -- postcode table
+ IF for_place_id IS NULL THEN
+ SELECT parent_place_id, country_code, rank_search, postcode, 'place', 'postcode'
+ FROM location_postcode
+ WHERE place_id = in_place_id
+ INTO for_place_id, searchcountrycode, searchrankaddress, searchpostcode,
+ searchclass, searchtype;
+ END IF;
+
+ -- POI objects in the placex table
IF for_place_id IS NULL THEN
- 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;
+ 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;
END IF;
+ -- 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.
IF for_place_id IS NULL THEN
select coalesce(linked_place_id, place_id), country_code,
housenumber, rank_search, postcode, null
--RAISE WARNING '% % % %',searchcountrycode, searchhousenumber, searchrankaddress, searchpostcode;
- found := 1000;
- hadcountry := false;
- FOR location IN
- select placex.place_id, osm_type, osm_id,
- CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as name,
- class, type, admin_level, true as fromarea, true 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
+ 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
LOOP
--RAISE WARNING '%',location;
IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
searchcountrycode := location.country_code;
END IF;
- IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
- location.isaddress := FALSE;
- END IF;
- IF searchpostcode IS NULL and location.postcode IS NOT NULL THEN
- searchpostcode := location.postcode;
- END IF;
- IF location.rank_address = 4 AND location.isaddress THEN
- hadcountry := true;
+ IF location.rank_address < 4 THEN
+ -- no country locations for ranks higher than country
+ searchcountrycode := NULL;
END IF;
- IF location.rank_address < 4 AND NOT hadcountry THEN
- select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
- IF countryname IS NOT NULL THEN
- countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
- RETURN NEXT countrylocation;
- END IF;
- END IF;
- 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,
- location.distance)::addressline;
+ 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;
RETURN NEXT countrylocation;
found := location.rank_address;
END LOOP;
- FOR location IN
- select placex.place_id, osm_type, osm_id,
- CASE WHEN class = 'place' and type = 'postcode' THEN hstore('name', postcode) ELSE name END as 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 address_place_id = for_place_id AND rank_address = 0 THEN 100 WHEN rank_address = 11 THEN 5 ELSE rank_address END as rank_address,
- 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 > 0 AND cached_rank_address < searchrankaddress)
- and address_place_id != for_place_id
- 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
+ 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
LOOP
--RAISE WARNING '%',location;
IF searchcountrycode IS NULL AND location.country_code IS NOT NULL THEN
searchcountrycode := location.country_code;
END IF;
- IF searchpostcode IS NOT NULL and location.type = 'postcode' THEN
- location.isaddress := FALSE;
- END IF;
- IF searchpostcode IS NULL and location.isaddress and location.type != 'postcode' and location.postcode IS NOT NULL THEN
- searchpostcode := location.postcode;
- END IF;
- IF location.rank_address = 4 AND location.isaddress THEN
- hadcountry := true;
- END IF;
- IF location.rank_address < 4 AND NOT hadcountry THEN
- select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
- IF countryname IS NOT NULL THEN
- countrylocation := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
- RETURN NEXT countrylocation;
+ IF location.type in ('postcode', 'postal_code') THEN
+ postcode_isaddress := false;
+ IF location.osm_type != 'R' THEN
+ location.isaddress := FALSE;
END IF;
END IF;
- 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,
+ 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,
location.distance)::addressline;
RETURN NEXT countrylocation;
found := location.rank_address;
END LOOP;
+ -- If no country was included yet, add the name information from country_name.
IF found > 4 THEN
- select name from country_name where country_code = searchcountrycode limit 1 INTO countryname;
+ SELECT name FROM country_name
+ WHERE country_code = searchcountrycode LIMIT 1 INTO countryname;
--RAISE WARNING '% % %',found,searchcountrycode,countryname;
IF countryname IS NOT NULL THEN
- location := ROW(null, null, null, countryname, 'place', 'country', null, true, true, 4, 0)::addressline;
+ location := ROW(null, null, null, countryname, 'place', 'country',
+ null, true, true, 4, 0)::addressline;
RETURN NEXT location;
END IF;
END IF;
+ -- Finally add some artificial rows.
IF searchcountrycode IS NOT NULL THEN
- location := ROW(null, null, null, hstore('ref', searchcountrycode), 'place', 'country_code', null, true, false, 4, 0)::addressline;
+ location := ROW(null, null, null, hstore('ref', searchcountrycode),
+ 'place', 'country_code', null, true, false, 4, 0)::addressline;
RETURN NEXT location;
END IF;
IF searchhousename IS NOT NULL THEN
- location := ROW(in_place_id, null, null, searchhousename, searchclass, searchtype, null, true, true, 29, 0)::addressline;
--- location := ROW(in_place_id, null, null, searchhousename, 'place', 'house_name', null, true, true, 29, 0)::addressline;
+ location := ROW(in_place_id, null, null, searchhousename, searchclass,
+ searchtype, null, true, true, 29, 0)::addressline;
RETURN NEXT location;
END IF;
IF searchhousenumber IS NOT NULL THEN
- location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber), 'place', 'house_number', null, true, true, 28, 0)::addressline;
+ location := ROW(in_place_id, null, null, hstore('ref', searchhousenumber),
+ 'place', 'house_number', null, true, true, 28, 0)::addressline;
RETURN NEXT location;
END IF;
IF searchpostcode IS NOT NULL THEN
- location := ROW(null, null, null, hstore('ref', searchpostcode), 'place', 'postcode', null, true, true, 5, 0)::addressline;
+ location := ROW(null, null, null, hstore('ref', searchpostcode), 'place',
+ 'postcode', null, false, postcode_isaddress, 5, 0)::addressline;
RETURN NEXT location;
END IF;
LANGUAGE plpgsql;
-CREATE OR REPLACE FUNCTION get_searchrank_label(rank INTEGER) RETURNS TEXT
- AS $$
-DECLARE
-BEGIN
- IF rank < 2 THEN
- RETURN 'Continent';
- ELSEIF rank < 4 THEN
- RETURN 'Sea';
- ELSEIF rank < 8 THEN
- RETURN 'Country';
- ELSEIF rank < 12 THEN
- RETURN 'State';
- ELSEIF rank < 16 THEN
- RETURN 'County';
- ELSEIF rank = 16 THEN
- RETURN 'City';
- ELSEIF rank = 17 THEN
- RETURN 'Town / Island';
- ELSEIF rank = 18 THEN
- RETURN 'Village / Hamlet';
- ELSEIF rank = 20 THEN
- RETURN 'Suburb';
- ELSEIF rank = 21 THEN
- RETURN 'Postcode Area';
- ELSEIF rank = 22 THEN
- RETURN 'Croft / Farm / Locality / Islet';
- ELSEIF rank = 23 THEN
- RETURN 'Postcode Area';
- ELSEIF rank = 25 THEN
- RETURN 'Postcode Point';
- ELSEIF rank = 26 THEN
- RETURN 'Street / Major Landmark';
- ELSEIF rank = 27 THEN
- RETURN 'Minory Street / Path';
- ELSEIF rank = 28 THEN
- RETURN 'House / Building';
- ELSE
- RETURN 'Other: '||rank;
- END IF;
-
-END;
-$$
-LANGUAGE plpgsql;
-
-CREATE OR REPLACE FUNCTION get_addressrank_label(rank INTEGER) RETURNS TEXT
- AS $$
-DECLARE
-BEGIN
- IF rank = 0 THEN
- RETURN 'None';
- ELSEIF rank < 2 THEN
- RETURN 'Continent';
- ELSEIF rank < 4 THEN
- RETURN 'Sea';
- ELSEIF rank = 5 THEN
- RETURN 'Postcode';
- ELSEIF rank < 8 THEN
- RETURN 'Country';
- ELSEIF rank < 12 THEN
- RETURN 'State';
- ELSEIF rank < 16 THEN
- RETURN 'County';
- ELSEIF rank = 16 THEN
- RETURN 'City';
- ELSEIF rank = 17 THEN
- RETURN 'Town / Village / Hamlet';
- ELSEIF rank = 20 THEN
- RETURN 'Suburb';
- ELSEIF rank = 21 THEN
- RETURN 'Postcode Area';
- ELSEIF rank = 22 THEN
- RETURN 'Croft / Farm / Locality / Islet';
- ELSEIF rank = 23 THEN
- RETURN 'Postcode Area';
- ELSEIF rank = 25 THEN
- RETURN 'Postcode Point';
- ELSEIF rank = 26 THEN
- RETURN 'Street / Major Landmark';
- ELSEIF rank = 27 THEN
- RETURN 'Minory Street / Path';
- ELSEIF rank = 28 THEN
- RETURN 'House / Building';
- ELSE
- RETURN 'Other: '||rank;
- END IF;
-
-END;
-$$
-LANGUAGE plpgsql;
-
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 $$
IF out_postcode IS NULL THEN
SELECT postcode from placex where place_id = out_parent_place_id INTO out_postcode;
END IF;
- IF out_postcode IS NULL THEN
- out_postcode := getNearestPostcode(out_partition, place_centroid);
- END IF;
+ -- XXX look into postcode table
newpoints := 0;
insert into location_property_aux (place_id, partition, parent_place_id, housenumber, postcode, centroid)
$$
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
+ FOR match IN SELECT * FROM get_wikipedia_match(extratags, country_code)
+ WHERE language is not NULL
+ LOOP
+ result.importance := match.importance;
+ result.wikipedia := match.language || ':' || match.title;
+ RETURN result;
+ END LOOP;
+
+ 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;
+
+ RETURN null;
+END;
+$$
+LANGUAGE plpgsql;
+
CREATE OR REPLACE FUNCTION quad_split_geometry(geometry GEOMETRY, maxarea FLOAT, maxdepth INTEGER)
RETURNS SETOF GEOMETRY
AS $$
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))
- 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'));
+ 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'));
update placex set indexed_status = 2 where (st_covers(geom, placex.geometry) OR ST_Intersects(geom, placex.geometry))
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'));
END LOOP;