add support for new middle table format of osm2pgsql

Functions are adapted according to the format detected from the
osm2pgsql property table.
This commit is contained in:
Sarah Hoffmann 2024-02-15 16:19:56 +01:00
parent a4f2e6a893
commit 36b1660121
5 changed files with 163 additions and 29 deletions

View File

@ -119,12 +119,14 @@ CREATE OR REPLACE FUNCTION find_associated_street(poi_osm_type CHAR(1),
AS $$
DECLARE
location RECORD;
member JSONB;
parent RECORD;
result BIGINT;
distance FLOAT;
new_distance FLOAT;
waygeom GEOMETRY;
BEGIN
{% if db.middle_db_format == '1' %}
FOR location IN
SELECT members FROM planet_osm_rels
WHERE parts @> ARRAY[poi_osm_id]
@ -161,6 +163,40 @@ BEGIN
END LOOP;
END LOOP;
{% else %}
FOR member IN
SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(members)
WHERE planet_osm_member_ids(members, poi_osm_type::char(1)) && ARRAY[poi_osm_id]
and tags->>'type' = 'associatedStreet'
and value->>'role' = 'street'
LOOP
FOR parent IN
SELECT place_id, geometry
FROM placex
WHERE osm_type = (member->>'type')::char(1)
and osm_id = (member->>'ref')::bigint
and name is not null
and rank_search between 26 and 27
LOOP
-- Find the closest 'street' member.
-- Avoid distance computation for the frequent case where there is
-- only one street member.
IF waygeom is null THEN
result := parent.place_id;
waygeom := parent.geometry;
ELSE
distance := coalesce(distance, ST_Distance(waygeom, bbox));
new_distance := ST_Distance(parent.geometry, bbox);
IF new_distance < distance THEN
distance := new_distance;
result := parent.place_id;
waygeom := parent.geometry;
END IF;
END IF;
END LOOP;
END LOOP;
{% endif %}
RETURN result;
END;
$$
@ -257,7 +293,11 @@ CREATE OR REPLACE FUNCTION find_linked_place(bnd placex)
RETURNS placex
AS $$
DECLARE
{% if db.middle_db_format == '1' %}
relation_members TEXT[];
{% else %}
relation_members JSONB;
{% endif %}
rel_member RECORD;
linked_placex placex%ROWTYPE;
bnd_name TEXT;
@ -749,7 +789,11 @@ CREATE OR REPLACE FUNCTION placex_update()
DECLARE
i INTEGER;
location RECORD;
{% if db.middle_db_format == '1' %}
relation_members TEXT[];
{% else %}
relation_member JSONB;
{% endif %}
geom GEOMETRY;
parent_address_level SMALLINT;
@ -971,6 +1015,7 @@ BEGIN
-- 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
{% if db.middle_db_format == '1' %}
FOR relation_members IN select members from planet_osm_rels r where r.id = NEW.osm_id and r.parts != array[]::bigint[]
LOOP
FOR i IN 1..array_upper(relation_members, 1) BY 2 LOOP
@ -989,6 +1034,29 @@ BEGIN
END IF;
END LOOP;
END LOOP;
{% else %}
FOR relation_member IN
SELECT value FROM planet_osm_rels r, LATERAL jsonb_array_elements(r.members)
WHERE r.id = NEW.osm_id
LOOP
IF relation_member->>'role' IN ('', 'main_stream', 'side_stream')
and relation_member->>'type' = 'W'
THEN
{% if debug %}RAISE WARNING 'waterway parent %, child %', NEW.osm_id, relation_member;{% endif %}
FOR linked_node_id IN
SELECT place_id FROM placex
WHERE osm_type = 'W' and osm_id = (relation_member->>'ref')::bigint
and class = NEW.class and type in ('river', 'stream', 'canal', 'drain', 'ditch')
and (relation_member->>'role' != 'side_stream' or NEW.name->'name' = name->'name')
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;
{% endif %}
END LOOP;
END IF;
END LOOP;
{% endif %}
{% if debug %}RAISE WARNING 'Waterway processed';{% endif %}
END IF;

View File

@ -73,6 +73,26 @@ END;
$$
LANGUAGE plpgsql IMMUTABLE;
CREATE OR REPLACE FUNCTION get_rel_node_members(members JSONB, memberLabels TEXT[])
RETURNS SETOF BIGINT
AS $$
DECLARE
member JSONB;
BEGIN
FOR member IN SELECT * FROM jsonb_array_elements(members)
LOOP
IF member->>'type' = 'N' and member->>'role' = ANY(memberLabels) THEN
RETURN NEXT (member->>'ref')::bigint;
END IF;
END LOOP;
RETURN;
END;
$$
LANGUAGE plpgsql IMMUTABLE;
-- Copy 'name' to or from the default language.
--
-- \param country_code Country code of the object being named.

View File

@ -298,7 +298,15 @@ CREATE TABLE IF NOT EXISTS wikipedia_redirect (
-- osm2pgsql does not create indexes on the middle tables for Nominatim
-- Add one for lookup of associated street relations.
CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];
{% if db.middle_db_format == '1' %}
CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts)
{{db.tablespace.address_index}}
WHERE tags @> ARRAY['associatedStreet'];
{% else %}
CREATE INDEX planet_osm_rels_relation_members_idx ON planet_osm_rels USING gin(planet_osm_member_ids(members, 'R'::character(1)))
WITH (fastupdate=off)
{{db.tablespace.address_index}};
{% endif %}
-- Needed for lookups if a node is part of an interpolation.
CREATE INDEX IF NOT EXISTS idx_place_interpolations

View File

@ -7,7 +7,7 @@
"""
Preprocessing of SQL files.
"""
from typing import Set, Dict, Any
from typing import Set, Dict, Any, cast
import jinja2
from nominatim.db.connection import Connection
@ -28,13 +28,24 @@ def _get_partitions(conn: Connection) -> Set[int]:
def _get_tables(conn: Connection) -> Set[str]:
""" Return the set of tables currently in use.
Only includes non-partitioned
"""
with conn.cursor() as cur:
cur.execute("SELECT tablename FROM pg_tables WHERE schemaname = 'public'")
return set((row[0] for row in list(cur)))
def _get_middle_db_format(conn: Connection, tables: Set[str]) -> str:
""" Returns the version of the slim middle tables.
"""
if 'osm2pgsql_properties' not in tables:
return '1'
with conn.cursor() as cur:
cur.execute("SELECT value FROM osm2pgsql_properties WHERE property = 'db_format'")
row = cur.fetchone()
return cast(str, row[0]) if row is not None else '1'
def _setup_tablespace_sql(config: Configuration) -> Dict[str, str]:
""" Returns a dict with tablespace expressions for the different tablespace
@ -84,6 +95,7 @@ class SQLPreprocessor:
db_info['tables'] = _get_tables(conn)
db_info['reverse_only'] = 'search_name' not in db_info['tables']
db_info['tablespace'] = _setup_tablespace_sql(config)
db_info['middle_db_format'] = _get_middle_db_format(conn, db_info['tables'])
self.env.globals['config'] = config
self.env.globals['db'] = db_info

View File

@ -52,33 +52,52 @@ def add_data_to_planet_relations(context):
for tests on data that looks up members.
"""
with context.db.cursor() as cur:
for r in context.table:
last_node = 0
last_way = 0
parts = []
if r['members']:
members = []
for m in r['members'].split(','):
mid = NominatimID(m)
if mid.typ == 'N':
parts.insert(last_node, int(mid.oid))
last_node += 1
last_way += 1
elif mid.typ == 'W':
parts.insert(last_way, int(mid.oid))
last_way += 1
else:
parts.append(int(mid.oid))
cur.execute("SELECT value FROM osm2pgsql_properties WHERE property = 'db_format'")
row = cur.fetchone()
if row is None or row[0] == '1':
for r in context.table:
last_node = 0
last_way = 0
parts = []
if r['members']:
members = []
for m in r['members'].split(','):
mid = NominatimID(m)
if mid.typ == 'N':
parts.insert(last_node, int(mid.oid))
last_node += 1
last_way += 1
elif mid.typ == 'W':
parts.insert(last_way, int(mid.oid))
last_way += 1
else:
parts.append(int(mid.oid))
members.extend((mid.typ.lower() + mid.oid, mid.cls or ''))
else:
members = None
members.extend((mid.typ.lower() + mid.oid, mid.cls or ''))
else:
members = None
tags = chain.from_iterable([(h[5:], r[h]) for h in r.headings if h.startswith("tags+")])
tags = chain.from_iterable([(h[5:], r[h]) for h in r.headings if h.startswith("tags+")])
cur.execute("""INSERT INTO planet_osm_rels (id, way_off, rel_off, parts, members, tags)
VALUES (%s, %s, %s, %s, %s, %s)""",
(r['id'], last_node, last_way, parts, members, list(tags)))
cur.execute("""INSERT INTO planet_osm_rels (id, way_off, rel_off, parts, members, tags)
VALUES (%s, %s, %s, %s, %s, %s)""",
(r['id'], last_node, last_way, parts, members, list(tags)))
else:
for r in context.table:
if r['members']:
members = []
for m in r['members'].split(','):
mid = NominatimID(m)
members.append({'ref': mid.oid, 'role': mid.cls or '', 'type': mid.typ})
else:
members = []
tags = {h[5:]: r[h] for h in r.headings if h.startswith("tags+")}
cur.execute("""INSERT INTO planet_osm_rels (id, tags, members)
VALUES (%s, %s, %s)""",
(r['id'], psycopg2.extras.Json(tags),
psycopg2.extras.Json(members)))
@given("the ways")
def add_data_to_planet_ways(context):
@ -86,12 +105,19 @@ def add_data_to_planet_ways(context):
tests on that that looks up node ids in this table.
"""
with context.db.cursor() as cur:
cur.execute("SELECT value FROM osm2pgsql_properties WHERE property = 'db_format'")
row = cur.fetchone()
json_tags = row is not None and row[0] != '1'
for r in context.table:
tags = chain.from_iterable([(h[5:], r[h]) for h in r.headings if h.startswith("tags+")])
if json_tags:
tags = psycopg2.extras.Json({h[5:]: r[h] for h in r.headings if h.startswith("tags+")})
else:
tags = list(chain.from_iterable([(h[5:], r[h])
for h in r.headings if h.startswith("tags+")]))
nodes = [ int(x.strip()) for x in r['nodes'].split(',') ]
cur.execute("INSERT INTO planet_osm_ways (id, nodes, tags) VALUES (%s, %s, %s)",
(r['id'], nodes, list(tags)))
(r['id'], nodes, tags))
################################ WHEN ##################################