forked from hans/Nominatim
rework postcode computation
Now adds areas to location_postcodes, ignores postcode points inside areas and supports customizable extents.
This commit is contained in:
@@ -2,10 +2,10 @@
|
||||
--
|
||||
-- This file is part of Nominatim. (https://nominatim.org)
|
||||
--
|
||||
-- Copyright (C) 2022 by the Nominatim developer community.
|
||||
-- Copyright (C) 2025 by the Nominatim developer community.
|
||||
-- For a full list of authors see the git log.
|
||||
|
||||
-- Trigger functions for location_postcode table.
|
||||
-- Trigger functions for location_postcodes table.
|
||||
|
||||
|
||||
-- Trigger for updates of location_postcode
|
||||
@@ -13,7 +13,7 @@
|
||||
-- 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()
|
||||
CREATE OR REPLACE FUNCTION postcodes_update()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
@@ -28,13 +28,10 @@ BEGIN
|
||||
|
||||
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.geometry, NEW.rank_search)
|
||||
FROM getNearFeatures(partition, NEW.centroid, NEW.centroid, NEW.rank_search)
|
||||
WHERE NOT isguess ORDER BY rank_address DESC, distance asc LIMIT 1
|
||||
LOOP
|
||||
NEW.parent_place_id = location.place_id;
|
||||
@@ -45,3 +42,89 @@ END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION postcodes_delete()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
BEGIN
|
||||
{% if not disable_diff_updates %}
|
||||
UPDATE placex p SET indexed_status = 2
|
||||
WHERE p.postcode = OLD.postcode AND ST_Intersects(OLD.geometry, p.geometry)
|
||||
AND indexed_status = 0;
|
||||
{% endif %}
|
||||
|
||||
RETURN OLD;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION postcodes_insert()
|
||||
RETURNS TRIGGER
|
||||
AS $$
|
||||
DECLARE
|
||||
existing RECORD;
|
||||
BEGIN
|
||||
IF NEW.osm_id is not NULL THEN
|
||||
-- postcode area, remove existing from same OSM object
|
||||
SELECT * INTO existing FROM location_postcodes p
|
||||
WHERE p.osm_id = NEW.osm_id;
|
||||
|
||||
IF existing.place_id is not NULL THEN
|
||||
IF existing.postcode != NEW.postcode or existing.country_code != NEW.country_code THEN
|
||||
DELETE FROM location_postcodes p WHERE p.osm_id = NEW.osm_id;
|
||||
existing := NULL;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF existing is NULL THEN
|
||||
SELECT * INTO existing FROM location_postcodes p
|
||||
WHERE p.country_code = NEW.country_code AND p.postcode = NEW.postcode;
|
||||
|
||||
IF existing.postcode is NULL THEN
|
||||
{% if not disable_diff_updates %}
|
||||
UPDATE placex p SET indexed_status = 2
|
||||
WHERE ST_Intersects(NEW.geometry, p.geometry)
|
||||
AND indexed_status = 0
|
||||
AND p.rank_address >= 22 AND not p.address ? 'postcode';
|
||||
{% endif %}
|
||||
|
||||
-- new entry, just insert
|
||||
NEW.indexed_status := 1;
|
||||
NEW.place_id := nextval('seq_place');
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- update: only when there are changes
|
||||
IF coalesce(NEW.osm_id, -1) != coalesce(existing.osm_id, -1)
|
||||
OR (NEW.osm_id is not null AND NEW.geometry::text != existing.geometry::text)
|
||||
OR (NEW.osm_id is null
|
||||
AND (abs(ST_X(existing.centroid) - ST_X(NEW.centroid)) > 0.0000001
|
||||
OR abs(ST_Y(existing.centroid) - ST_Y(NEW.centroid)) > 0.0000001))
|
||||
THEN
|
||||
{% if not disable_diff_updates %}
|
||||
UPDATE placex p SET indexed_status = 2
|
||||
WHERE ST_Intersects(ST_Difference(NEW.geometry, existing.geometry), p.geometry)
|
||||
AND indexed_status = 0
|
||||
AND p.rank_address >= 22 AND not p.address ? 'postcode';
|
||||
|
||||
UPDATE placex p SET indexed_status = 2
|
||||
WHERE ST_Intersects(ST_Difference(existing.geometry, NEW.geometry), p.geometry)
|
||||
AND indexed_status = 0
|
||||
AND p.postcode = OLD.postcode;
|
||||
{% endif %}
|
||||
|
||||
UPDATE location_postcodes p
|
||||
SET osm_id = NEW.osm_id,
|
||||
indexed_status = 2,
|
||||
centroid = NEW.centroid,
|
||||
geometry = NEW.geometry
|
||||
WHERE p.country_code = NEW.country_code AND p.postcode = NEW.postcode;
|
||||
END IF;
|
||||
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
@@ -2,7 +2,7 @@
|
||||
--
|
||||
-- This file is part of Nominatim. (https://nominatim.org)
|
||||
--
|
||||
-- Copyright (C) 2022 by the Nominatim developer community.
|
||||
-- Copyright (C) 2025 by the Nominatim developer community.
|
||||
-- For a full list of authors see the git log.
|
||||
|
||||
-- Functions related to search and address ranks
|
||||
@@ -114,66 +114,6 @@ $$
|
||||
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE;
|
||||
|
||||
|
||||
-- Guess a ranking for postcodes from country and postcode format.
|
||||
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 PARALLEL SAFE;
|
||||
|
||||
|
||||
-- Get standard search and address rank for an object.
|
||||
--
|
||||
-- \param country Two-letter country code where the object is in.
|
||||
@@ -198,12 +138,7 @@ AS $$
|
||||
DECLARE
|
||||
classtype TEXT;
|
||||
BEGIN
|
||||
IF place_class in ('place','boundary')
|
||||
and place_type in ('postcode','postal_code')
|
||||
THEN
|
||||
SELECT * INTO search_rank, address_rank
|
||||
FROM get_postcode_rank(country, postcode);
|
||||
ELSEIF extended_type = 'N' AND place_class = 'highway' THEN
|
||||
IF extended_type = 'N' AND place_class = 'highway' THEN
|
||||
search_rank = 30;
|
||||
address_rank = 30;
|
||||
ELSEIF place_class = 'landuse' AND extended_type != 'A' THEN
|
||||
|
||||
@@ -323,6 +323,17 @@ END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
|
||||
-- Return the bounding box of the geometry buffered by the given number
|
||||
-- of meters.
|
||||
CREATE OR REPLACE FUNCTION expand_by_meters(geom GEOMETRY, meters FLOAT)
|
||||
RETURNS GEOMETRY
|
||||
AS $$
|
||||
SELECT ST_Envelope(ST_Buffer(geom::geography, meters, 1)::geometry)
|
||||
$$
|
||||
LANGUAGE sql IMMUTABLE PARALLEL SAFE;
|
||||
|
||||
|
||||
-- Create a bounding box with an extent computed from the radius (in meters)
|
||||
-- which in turn is derived from the given search rank.
|
||||
CREATE OR REPLACE FUNCTION place_node_fuzzy_area(geom GEOMETRY, rank_search INTEGER)
|
||||
@@ -341,9 +352,7 @@ BEGIN
|
||||
radius := 1000;
|
||||
END IF;
|
||||
|
||||
RETURN ST_Envelope(ST_Collect(
|
||||
ST_Project(geom::geography, radius, 0.785398)::geometry,
|
||||
ST_Project(geom::geography, radius, 3.9269908)::geometry));
|
||||
RETURN expand_by_meters(geom, radius);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE;
|
||||
|
||||
Reference in New Issue
Block a user