forked from hans/Nominatim
reorganise layout of location_postcode table
Also renames the table as this will make it easier to migrate.
This commit is contained in:
@@ -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.
|
||||
|
||||
{% include('functions/utils.sql') %}
|
||||
@@ -18,7 +18,7 @@
|
||||
{% include 'functions/placex_triggers.sql' %}
|
||||
{% endif %}
|
||||
|
||||
{% if 'location_postcode' in db.tables %}
|
||||
{% if 'location_postcodes' in db.tables %}
|
||||
{% include 'functions/postcode_triggers.sql' %}
|
||||
{% endif %}
|
||||
|
||||
|
||||
@@ -1399,7 +1399,7 @@ BEGIN
|
||||
|
||||
{% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}
|
||||
|
||||
UPDATE location_postcode SET indexed_status = 2 WHERE parent_place_id = OLD.place_id;
|
||||
UPDATE location_postcodes SET indexed_status = 2 WHERE parent_place_id = OLD.place_id;
|
||||
|
||||
RETURN OLD;
|
||||
|
||||
|
||||
@@ -139,37 +139,46 @@ $$
|
||||
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE;
|
||||
|
||||
|
||||
-- Find the nearest artificial postcode for the given geometry.
|
||||
-- TODO For areas there should not be more than two inside the geometry.
|
||||
-- Find the best-matching postcode for the given geometry
|
||||
CREATE OR REPLACE FUNCTION get_nearest_postcode(country VARCHAR(2), geom GEOMETRY)
|
||||
RETURNS TEXT
|
||||
AS $$
|
||||
DECLARE
|
||||
outcode TEXT;
|
||||
cnt INTEGER;
|
||||
location RECORD;
|
||||
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;
|
||||
SELECT min(postcode), count(*) FROM
|
||||
(SELECT postcode FROM location_postcodes
|
||||
WHERE geom && location_postcodes.geometry -- want to use the index
|
||||
AND ST_Contains(geom, location_postcodes.centroid)
|
||||
AND country_code = country
|
||||
LIMIT 2) sub
|
||||
INTO outcode, cnt;
|
||||
|
||||
IF cnt = 1 THEN
|
||||
RETURN outcode;
|
||||
ELSE
|
||||
RETURN null;
|
||||
END IF;
|
||||
|
||||
RETURN null;
|
||||
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;
|
||||
-- Otherwise: be fully within the coverage area of a postcode
|
||||
FOR location IN
|
||||
SELECT postcode
|
||||
FROM location_postcodes p
|
||||
WHERE ST_Covers(p.geometry, geom)
|
||||
AND p.country_code = country
|
||||
ORDER BY osm_id is null, ST_Distance(p.centroid, geom)
|
||||
LIMIT 1
|
||||
LOOP
|
||||
RETURN location.postcode;
|
||||
END LOOP;
|
||||
|
||||
RETURN outcode;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql STABLE PARALLEL SAFE;
|
||||
|
||||
@@ -48,9 +48,6 @@ CREATE INDEX IF NOT EXISTS idx_osmline_parent_place_id
|
||||
---
|
||||
CREATE INDEX IF NOT EXISTS idx_osmline_parent_osm_id
|
||||
ON location_property_osmline USING BTREE (osm_id) {{db.tablespace.search_index}};
|
||||
---
|
||||
CREATE INDEX IF NOT EXISTS idx_postcode_postcode
|
||||
ON location_postcode USING BTREE (postcode) {{db.tablespace.search_index}};
|
||||
|
||||
{% if drop %}
|
||||
---
|
||||
@@ -77,8 +74,8 @@ CREATE INDEX IF NOT EXISTS idx_postcode_postcode
|
||||
deferred BOOLEAN
|
||||
);
|
||||
---
|
||||
CREATE INDEX IF NOT EXISTS idx_location_postcode_parent_place_id
|
||||
ON location_postcode USING BTREE (parent_place_id) {{db.tablespace.address_index}};
|
||||
CREATE INDEX IF NOT EXISTS idx_location_postcodes_parent_place_id
|
||||
ON location_postcodes USING BTREE (parent_place_id) {{db.tablespace.address_index}};
|
||||
{% endif %}
|
||||
|
||||
-- Indices only needed for search.
|
||||
|
||||
@@ -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.
|
||||
|
||||
-- insert creates the location tables, creates location indexes if indexed == true
|
||||
@@ -25,5 +25,5 @@ CREATE TRIGGER place_before_delete BEFORE DELETE ON place
|
||||
CREATE TRIGGER place_before_insert BEFORE INSERT ON place
|
||||
FOR EACH ROW EXECUTE PROCEDURE place_insert();
|
||||
|
||||
CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
|
||||
CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcodes
|
||||
FOR EACH ROW EXECUTE PROCEDURE postcode_update();
|
||||
|
||||
@@ -227,21 +227,29 @@ GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
|
||||
GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
|
||||
|
||||
-- Table for synthetic postcodes.
|
||||
DROP TABLE IF EXISTS location_postcode;
|
||||
CREATE TABLE location_postcode (
|
||||
place_id BIGINT,
|
||||
DROP TABLE IF EXISTS location_postcodes;
|
||||
CREATE TABLE location_postcodes (
|
||||
place_id BIGINT NOT NULL,
|
||||
parent_place_id BIGINT,
|
||||
osm_id BIGINT,
|
||||
rank_search SMALLINT,
|
||||
rank_address SMALLINT,
|
||||
indexed_status SMALLINT,
|
||||
indexed_date TIMESTAMP,
|
||||
country_code varchar(2),
|
||||
postcode TEXT,
|
||||
geometry GEOMETRY(Geometry, 4326)
|
||||
postcode TEXT NOT NULL,
|
||||
centroid GEOMETRY(Geometry, 4326) NOT NULL,
|
||||
geometry GEOMETRY(Geometry, 4326) NOT NULL
|
||||
);
|
||||
CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {{db.tablespace.search_index}};
|
||||
CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
|
||||
GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
|
||||
CREATE UNIQUE INDEX idx_location_postcodes_id ON location_postcodes
|
||||
USING BTREE (place_id) {{db.tablespace.search_index}};
|
||||
CREATE INDEX idx_location_postcodes_geometry ON location_postcodes
|
||||
USING GIST (geometry) {{db.tablespace.search_index}};
|
||||
CREATE INDEX IF NOT EXISTS idx_location_postcodes_postcode
|
||||
ON location_postcodes USING BTREE (postcode, country_code)
|
||||
{{db.tablespace.search_index}};
|
||||
CREATE INDEX IF NOT EXISTS idx_location_postcodes_osmid
|
||||
ON location_postcodes USING BTREE (osm_id) {{db.tablespace.search_index}};
|
||||
GRANT SELECT ON location_postcodes TO "{{config.DATABASE_WEBUSER}}" ;
|
||||
|
||||
-- Table to store location of entrance nodes
|
||||
DROP TABLE IF EXISTS placex_entrance;
|
||||
|
||||
Reference in New Issue
Block a user