Merge pull request #3939 from lonvia/more-table-constraints

Add NOT NULL and UNIQUE contraints on tables
This commit is contained in:
Sarah Hoffmann
2026-01-14 15:04:45 +01:00
committed by GitHub
9 changed files with 157 additions and 117 deletions

View File

@@ -2,7 +2,7 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2022 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
-- Functions for interpreting wkipedia/wikidata tags and computing importance.
@@ -166,7 +166,7 @@ BEGIN
END LOOP;
-- Nothing? Then try with the wikidata tag.
IF result.importance is null AND extratags ? 'wikidata' THEN
IF extratags ? 'wikidata' THEN
FOR match IN
{% if 'wikimedia_importance' in db.tables %}
SELECT * FROM wikimedia_importance
@@ -185,18 +185,18 @@ BEGIN
END IF;
-- Still nothing? Fall back to a default.
IF result.importance is null THEN
result.importance := 0.40001 - (rank_search::float / 75);
END IF;
result.importance := 0.40001 - (rank_search::float / 75);
{% if 'secondary_importance' in db.tables %}
FOR match IN
SELECT ST_Value(rast, centroid) as importance
FROM secondary_importance
WHERE ST_Intersects(ST_ConvexHull(rast), centroid) LIMIT 1
FROM secondary_importance
WHERE ST_Intersects(ST_ConvexHull(rast), centroid) LIMIT 1
LOOP
-- Secondary importance as tie breaker with 0.0001 weight.
result.importance := result.importance + match.importance::float / 655350000;
IF match.importance is not NULL THEN
-- Secondary importance as tie breaker with 0.0001 weight.
result.importance := result.importance + match.importance::float / 655350000;
END IF;
END LOOP;
{% endif %}

View File

@@ -2,7 +2,7 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2022 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
DROP TYPE IF EXISTS nearfeaturecentr CASCADE;
@@ -123,10 +123,12 @@ BEGIN
RETURN TRUE;
END IF;
IF in_rank_search <= 4 and not in_estimate THEN
INSERT INTO location_area_country (place_id, country_code, geometry)
(SELECT in_place_id, in_country_code, geom
FROM split_geometry(in_geometry) as geom);
IF in_rank_search <= 4 THEN
IF not in_estimate and in_country_code is not NULL THEN
INSERT INTO location_area_country (place_id, country_code, geometry)
(SELECT in_place_id, in_country_code, geom
FROM split_geometry(in_geometry) as geom);
END IF;
RETURN TRUE;
END IF;
@@ -212,7 +214,6 @@ DECLARE
BEGIN
{% for partition in db.partitions %}
IF in_partition = {{ partition }} THEN
DELETE FROM search_name_{{ partition }} values WHERE place_id = in_place_id;
IF in_rank_address > 0 THEN
INSERT INTO search_name_{{ partition }} (place_id, address_rank, name_vector, centroid)
values (in_place_id, in_rank_address, in_name_vector, in_geometry);
@@ -251,7 +252,6 @@ BEGIN
{% for partition in db.partitions %}
IF in_partition = {{ partition }} THEN
DELETE FROM location_road_{{ partition }} where place_id = in_place_id;
INSERT INTO location_road_{{ partition }} (partition, place_id, country_code, geometry)
values (in_partition, in_place_id, in_country_code, in_geometry);
RETURN TRUE;

View File

@@ -2,7 +2,7 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2025 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
CREATE OR REPLACE FUNCTION place_insert()
@@ -66,7 +66,8 @@ BEGIN
-- They get their parent from the interpolation.
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);
WHERE w.id = NEW.osm_id and p.osm_type = 'N' and p.osm_id = any(w.nodes)
and indexed_status = 0;
-- If there is already an entry in place, just update that, if necessary.
IF existing.osm_type is not null THEN

View File

@@ -2,7 +2,7 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2025 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
-- Trigger functions for the placex table.
@@ -465,7 +465,7 @@ BEGIN
END IF;
END LOOP;
name_vector := token_get_name_search_tokens(token_info);
name_vector := COALESCE(token_get_name_search_tokens(token_info), '{}'::INTEGER[]);
-- Check if the parent covers all address terms.
-- If not, create a search name entry with the house number as the name.
@@ -840,13 +840,15 @@ BEGIN
NEW.indexed_date = now();
{% if 'search_name' in db.tables %}
DELETE from search_name WHERE place_id = NEW.place_id;
{% endif %}
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);
IF OLD.indexed_status > 1 THEN
{% if 'search_name' in db.tables %}
DELETE from search_name WHERE place_id = NEW.place_id;
{% endif %}
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);
END IF;
NEW.extratags := NEW.extratags - 'linked_place'::TEXT;
IF NEW.extratags = ''::hstore THEN
@@ -859,10 +861,13 @@ BEGIN
NEW.linked_place_id := OLD.linked_place_id;
-- Remove linkage, if we have computed a different new linkee.
UPDATE placex SET linked_place_id = null, indexed_status = 2
WHERE linked_place_id = NEW.place_id
and (linked_place is null or place_id != linked_place);
-- update not necessary for osmline, cause linked_place_id does not exist
IF OLD.indexed_status > 1 THEN
UPDATE placex
SET linked_place_id = null,
indexed_status = CASE WHEN indexed_status = 0 THEN 2 ELSE indexed_status END
WHERE linked_place_id = NEW.place_id
and (linked_place is null or place_id != linked_place);
END IF;
-- Compute a preliminary centroid.
NEW.centroid := get_center_point(NEW.geometry);
@@ -1032,7 +1037,9 @@ BEGIN
LOOP
UPDATE placex SET linked_place_id = NEW.place_id WHERE place_id = linked_node_id;
{% if 'search_name' in db.tables %}
DELETE FROM search_name WHERE place_id = linked_node_id;
IF OLD.indexed_status > 1 THEN
DELETE FROM search_name WHERE place_id = linked_node_id;
END IF;
{% endif %}
END LOOP;
END IF;
@@ -1181,11 +1188,6 @@ BEGIN
-- reset the address rank if necessary.
UPDATE placex set linked_place_id = NEW.place_id, indexed_status = 2
WHERE place_id = location.place_id;
-- ensure that those places are not found anymore
{% if 'search_name' in db.tables %}
DELETE FROM search_name WHERE place_id = location.place_id;
{% endif %}
PERFORM deleteLocationArea(NEW.partition, location.place_id, NEW.rank_search);
SELECT wikipedia, importance
FROM compute_importance(location.extratags, NEW.country_code,
@@ -1196,7 +1198,7 @@ BEGIN
IF linked_importance is not null AND
(NEW.importance is null or NEW.importance < linked_importance)
THEN
NEW.importance = linked_importance;
NEW.importance := linked_importance;
END IF;
ELSE
-- No linked place? As a last resort check if the boundary is tagged with
@@ -1277,10 +1279,10 @@ BEGIN
NEW.postcode := coalesce(token_get_postcode(NEW.token_info), NEW.postcode);
-- if we have a name add this to the name search table
IF NEW.name IS NOT NULL THEN
name_vector := token_get_name_search_tokens(NEW.token_info);
IF array_length(name_vector, 1) is not NULL THEN
-- Initialise the name vector using our name
NEW.name := add_default_place_name(NEW.country_code, NEW.name);
name_vector := token_get_name_search_tokens(NEW.token_info);
IF NEW.rank_search <= 25 and NEW.rank_address > 0 THEN
result := add_location(NEW.place_id, NEW.country_code, NEW.partition,
@@ -1340,10 +1342,10 @@ BEGIN
-- RAISE WARNING 'placex_delete % %',OLD.osm_type,OLD.osm_id;
IF OLD.linked_place_id is null THEN
update placex set linked_place_id = null, indexed_status = 2 where linked_place_id = OLD.place_id and indexed_status = 0;
{% if debug %}RAISE WARNING 'placex_delete:01 % %',OLD.osm_type,OLD.osm_id;{% endif %}
update placex set linked_place_id = null where linked_place_id = OLD.place_id;
{% if debug %}RAISE WARNING 'placex_delete:02 % %',OLD.osm_type,OLD.osm_id;{% endif %}
UPDATE placex
SET linked_place_id = NULL,
indexed_status = CASE WHEN indexed_status = 0 THEN 2 ELSE indexed_status END
WHERE linked_place_id = OLD.place_id;
ELSE
update placex set indexed_status = 2 where place_id = OLD.linked_place_id and indexed_status = 0;
END IF;
@@ -1367,6 +1369,7 @@ BEGIN
-- 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;
UPDATE location_postcodes SET indexed_status = 2 WHERE parent_place_id = OLD.place_id;
END IF;
{% if debug %}RAISE WARNING 'placex_delete:08 % %',OLD.osm_type,OLD.osm_id;{% endif %}
@@ -1398,9 +1401,6 @@ BEGIN
END IF;
{% if debug %}RAISE WARNING 'placex_delete:12 % %',OLD.osm_type,OLD.osm_id;{% endif %}
UPDATE location_postcodes SET indexed_status = 2 WHERE parent_place_id = OLD.place_id;
RETURN OLD;
END;

View File

@@ -2,7 +2,7 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2025 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
-- Assorted helper functions for the triggers.
@@ -46,13 +46,13 @@ DECLARE
r INTEGER[];
BEGIN
IF array_upper(a, 1) IS NULL THEN
RETURN b;
RETURN COALESCE(b, '{}'::INTEGER[]);
END IF;
IF array_upper(b, 1) IS NULL THEN
RETURN a;
RETURN COALESCE(a, '{}'::INTEGER[]);
END IF;
r := a;
FOR i IN 1..array_upper(b, 1) LOOP
FOR i IN 1..array_upper(b, 1) LOOP
IF NOT (ARRAY[b[i]] <@ r) THEN
r := r || b[i];
END IF;
@@ -368,8 +368,6 @@ CREATE OR REPLACE FUNCTION add_location(place_id BIGINT, country_code varchar(2)
DECLARE
postcode TEXT;
BEGIN
PERFORM deleteLocationArea(partition, place_id, rank_search);
-- 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

View File

@@ -2,36 +2,48 @@
--
-- This file is part of Nominatim. (https://nominatim.org)
--
-- Copyright (C) 2022 by the Nominatim developer community.
-- Copyright (C) 2026 by the Nominatim developer community.
-- For a full list of authors see the git log.
drop table IF EXISTS search_name_blank CASCADE;
CREATE TABLE search_name_blank (
place_id BIGINT,
address_rank smallint,
name_vector integer[],
centroid GEOMETRY(Geometry, 4326)
place_id BIGINT NOT NULL,
address_rank smallint NOT NULL,
name_vector integer[] NOT NULL,
centroid GEOMETRY(Geometry, 4326) NOT NULL
);
{% for partition in db.partitions %}
CREATE TABLE location_area_large_{{ partition }} () INHERITS (location_area_large) {{db.tablespace.address_data}};
CREATE INDEX idx_location_area_large_{{ partition }}_place_id ON location_area_large_{{ partition }} USING BTREE (place_id) {{db.tablespace.address_index}};
CREATE INDEX idx_location_area_large_{{ partition }}_geometry ON location_area_large_{{ partition }} USING GIST (geometry) {{db.tablespace.address_index}};
CREATE INDEX idx_location_area_large_{{ partition }}_place_id
ON location_area_large_{{ partition }}
USING BTREE (place_id) {{db.tablespace.address_index}};
CREATE INDEX idx_location_area_large_{{ partition }}_geometry
ON location_area_large_{{ partition }}
USING GIST (geometry) {{db.tablespace.address_index}};
CREATE TABLE search_name_{{ partition }} () INHERITS (search_name_blank) {{db.tablespace.address_data}};
CREATE INDEX idx_search_name_{{ partition }}_place_id ON search_name_{{ partition }} USING BTREE (place_id) {{db.tablespace.address_index}};
CREATE INDEX idx_search_name_{{ partition }}_centroid_street ON search_name_{{ partition }} USING GIST (centroid) {{db.tablespace.address_index}} where address_rank between 26 and 27;
CREATE INDEX idx_search_name_{{ partition }}_centroid_place ON search_name_{{ partition }} USING GIST (centroid) {{db.tablespace.address_index}} where address_rank between 2 and 25;
CREATE UNIQUE INDEX idx_search_name_{{ partition }}_place_id
ON search_name_{{ partition }}
USING BTREE (place_id) {{db.tablespace.address_index}};
CREATE INDEX idx_search_name_{{ partition }}_centroid_street
ON search_name_{{ partition }} USING GIST (centroid) {{db.tablespace.address_index}}
WHERE address_rank between 26 and 27;
CREATE INDEX idx_search_name_{{ partition }}_centroid_place
ON search_name_{{ partition }} USING GIST (centroid) {{db.tablespace.address_index}}
WHERE address_rank between 2 and 25;
DROP TABLE IF EXISTS location_road_{{ partition }};
CREATE TABLE location_road_{{ partition }} (
place_id BIGINT,
partition SMALLINT,
place_id BIGINT NOT NULL,
partition SMALLINT NOT NULL,
country_code VARCHAR(2),
geometry GEOMETRY(Geometry, 4326)
geometry GEOMETRY(Geometry, 4326) NOT NULL
) {{db.tablespace.address_data}};
CREATE INDEX idx_location_road_{{ partition }}_geometry ON location_road_{{ partition }} USING GIST (geometry) {{db.tablespace.address_index}};
CREATE INDEX idx_location_road_{{ partition }}_place_id ON location_road_{{ partition }} USING BTREE (place_id) {{db.tablespace.address_index}};
CREATE INDEX idx_location_road_{{ partition }}_geometry
ON location_road_{{ partition }}
USING GIST (geometry) {{db.tablespace.address_index}};
CREATE UNIQUE INDEX idx_location_road_{{ partition }}_place_id
ON location_road_{{ partition }}
USING BTREE (place_id) {{db.tablespace.address_index}};
{% endfor %}

View File

@@ -34,53 +34,53 @@ GRANT SELECT ON TABLE nominatim_properties TO "{{config.DATABASE_WEBUSER}}";
drop table IF EXISTS location_area CASCADE;
CREATE TABLE location_area (
place_id BIGINT,
keywords INTEGER[],
partition SMALLINT,
place_id BIGINT NOT NULL,
keywords INTEGER[] NOT NULL,
partition SMALLINT NOT NULL,
rank_search SMALLINT NOT NULL,
rank_address SMALLINT NOT NULL,
country_code VARCHAR(2),
isguess BOOL,
isguess BOOL NOT NULL,
postcode TEXT,
centroid GEOMETRY(Point, 4326),
geometry GEOMETRY(Geometry, 4326)
centroid GEOMETRY(Point, 4326) NOT NULL,
geometry GEOMETRY(Geometry, 4326) NOT NULL
);
CREATE TABLE location_area_large () INHERITS (location_area);
DROP TABLE IF EXISTS location_area_country;
CREATE TABLE location_area_country (
place_id BIGINT,
country_code varchar(2),
geometry GEOMETRY(Geometry, 4326)
place_id BIGINT NOT NULL,
country_code varchar(2) NOT NULL,
geometry GEOMETRY(Geometry, 4326) NOT NULL
) {{db.tablespace.address_data}};
CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
CREATE TABLE location_property_tiger (
place_id BIGINT,
place_id BIGINT NOT NULL,
parent_place_id BIGINT,
startnumber INTEGER,
endnumber INTEGER,
step SMALLINT,
partition SMALLINT,
linegeo GEOMETRY,
startnumber INTEGER NOT NULL,
endnumber INTEGER NOT NULL,
step SMALLINT NOT NULL,
partition SMALLINT NOT NULL,
linegeo GEOMETRY NOT NULL,
postcode TEXT);
GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
drop table if exists location_property_osmline;
CREATE TABLE location_property_osmline (
place_id BIGINT NOT NULL,
osm_id BIGINT,
osm_id BIGINT NOT NULL,
parent_place_id BIGINT,
geometry_sector INTEGER,
geometry_sector INTEGER NOT NULL,
indexed_date TIMESTAMP,
startnumber INTEGER,
endnumber INTEGER,
step SMALLINT,
partition SMALLINT,
indexed_status SMALLINT,
linegeo GEOMETRY,
partition SMALLINT NOT NULL,
indexed_status SMALLINT NOT NULL,
linegeo GEOMETRY NOT NULL,
address HSTORE,
token_info JSONB, -- custom column for tokenizer use only
postcode TEXT,
@@ -95,27 +95,28 @@ GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
drop table IF EXISTS search_name;
{% if not db.reverse_only %}
CREATE TABLE search_name (
place_id BIGINT,
importance FLOAT,
search_rank SMALLINT,
address_rank SMALLINT,
name_vector integer[],
nameaddress_vector integer[],
place_id BIGINT NOT NULL,
importance FLOAT NOT NULL,
search_rank SMALLINT NOT NULL,
address_rank SMALLINT NOT NULL,
name_vector integer[] NOT NULL,
nameaddress_vector integer[] NOT NULL,
country_code varchar(2),
centroid GEOMETRY(Geometry, 4326)
centroid GEOMETRY(Geometry, 4326) NOT NULL
) {{db.tablespace.search_data}};
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
CREATE UNIQUE INDEX idx_search_name_place_id
ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
{% endif %}
drop table IF EXISTS place_addressline;
CREATE TABLE place_addressline (
place_id BIGINT,
address_place_id BIGINT,
distance FLOAT,
cached_rank_address SMALLINT,
fromarea boolean,
isaddress boolean
place_id BIGINT NOT NULL,
address_place_id BIGINT NOT NULL,
distance FLOAT NOT NULL,
cached_rank_address SMALLINT NOT NULL,
fromarea boolean NOT NULL,
isaddress boolean NOT NULL
) {{db.tablespace.search_data}};
CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
@@ -128,18 +129,18 @@ CREATE TABLE placex (
linked_place_id BIGINT,
importance FLOAT,
indexed_date TIMESTAMP,
geometry_sector INTEGER,
rank_address SMALLINT,
rank_search SMALLINT,
partition SMALLINT,
indexed_status SMALLINT,
geometry_sector INTEGER NOT NULL,
rank_address SMALLINT NOT NULL,
rank_search SMALLINT NOT NULL,
partition SMALLINT NOT NULL,
indexed_status SMALLINT NOT NULL,
LIKE place INCLUDING CONSTRAINTS,
wikipedia TEXT, -- calculated wikipedia article name (language:title)
token_info JSONB, -- custom column for tokenizer use only
country_code varchar(2),
housenumber TEXT,
postcode TEXT,
centroid GEOMETRY(Geometry, 4326)
centroid GEOMETRY(Geometry, 4326) NOT NULL
) {{db.tablespace.search_data}};
CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
@@ -214,10 +215,10 @@ CREATE TABLE location_postcodes (
place_id BIGINT NOT NULL,
parent_place_id BIGINT,
osm_id BIGINT,
rank_search SMALLINT,
indexed_status SMALLINT,
rank_search SMALLINT NOT NULL,
indexed_status SMALLINT NOT NULL,
indexed_date TIMESTAMP,
country_code varchar(2),
country_code varchar(2) NOT NULL,
postcode TEXT NOT NULL,
centroid GEOMETRY(Geometry, 4326) NOT NULL,
geometry GEOMETRY(Geometry, 4326) NOT NULL

View File

@@ -2,7 +2,7 @@
#
# This file is part of Nominatim. (https://nominatim.org)
#
# Copyright (C) 2024 by the Nominatim developer community.
# Copyright (C) 2026 by the Nominatim developer community.
# For a full list of authors see the git log.
"""
A connection pool that executes incoming queries in parallel.
@@ -27,20 +27,28 @@ class QueryPool:
The results of the queries is discarded.
"""
def __init__(self, dsn: str, pool_size: int = 1, **conn_args: Any) -> None:
self.is_cancelled = False
self.wait_time = 0.0
self.query_queue: 'asyncio.Queue[QueueItem]' = asyncio.Queue(maxsize=2 * pool_size)
self.pool = [asyncio.create_task(self._worker_loop(dsn, **conn_args))
self.pool = [asyncio.create_task(self._worker_loop_cancellable(dsn, **conn_args))
for _ in range(pool_size)]
async def put_query(self, query: psycopg.abc.Query, params: Any) -> None:
""" Schedule a query for execution.
"""
if self.is_cancelled:
await self.finish()
return
tstart = time.time()
await self.query_queue.put((query, params))
self.wait_time += time.time() - tstart
await asyncio.sleep(0)
if self.is_cancelled:
await self.finish()
async def finish(self) -> None:
""" Wait for all queries to finish and close the pool.
"""
@@ -56,6 +64,25 @@ class QueryPool:
if excp is not None:
raise excp
def clear_queue(self) -> None:
""" Drop all items silently that might still be queued.
"""
try:
while True:
self.query_queue.get_nowait()
except asyncio.QueueEmpty:
pass # expected
async def _worker_loop_cancellable(self, dsn: str, **conn_args: Any) -> None:
try:
await self._worker_loop(dsn, **conn_args)
except Exception as e:
# Make sure the exception is forwarded to the main function
self.is_cancelled = True
# clear the queue here to ensure that any put() that may be blocked returns
self.clear_queue()
raise e
async def _worker_loop(self, dsn: str, **conn_args: Any) -> None:
conn_args['autocommit'] = True
aconn = await psycopg.AsyncConnection.connect(dsn, **conn_args)

View File

@@ -2,7 +2,7 @@
#
# This file is part of Nominatim. (https://nominatim.org)
#
# Copyright (C) 2025 by the Nominatim developer community.
# Copyright (C) 2026 by the Nominatim developer community.
# For a full list of authors see the git log.
"""
Helper classes for filling the place table.
@@ -35,7 +35,8 @@ class PlaceColumn:
self._add_hstore(
'name',
'name',
''.join(random.choices(string.printable, k=random.randrange(30))),
''.join(random.choices(string.ascii_uppercase)
+ random.choices(string.printable, k=random.randrange(30))),
)
return self