1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2022 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 DROP TYPE IF EXISTS nearfeaturecentr CASCADE;
9 CREATE TYPE nearfeaturecentr AS (
12 rank_address smallint,
20 -- feature intersects geometry
21 -- for areas and linestrings they must touch at least along a line
22 CREATE OR REPLACE FUNCTION is_relevant_geometry(de9im TEXT, geom_type TEXT)
26 IF substring(de9im from 1 for 2) != 'FF' THEN
30 IF geom_type = 'ST_Point' THEN
31 RETURN substring(de9im from 4 for 1) = '0';
34 IF geom_type in ('ST_LineString', 'ST_MultiLineString') THEN
35 RETURN substring(de9im from 4 for 1) = '1';
38 RETURN substring(de9im from 4 for 1) = '2';
40 $$ LANGUAGE plpgsql IMMUTABLE;
42 CREATE OR REPLACE function getNearFeatures(in_partition INTEGER, feature GEOMETRY,
43 feature_centroid GEOMETRY,
45 RETURNS setof nearfeaturecentr AS $$
47 r nearfeaturecentr%rowtype;
50 {% for partition in db.partitions %}
51 IF in_partition = {{ partition }} THEN
53 SELECT place_id, keywords, rank_address, rank_search,
54 CASE WHEN isguess THEN ST_Distance(feature, centroid)
55 ELSE min(ST_Distance(feature_centroid, geometry))
56 -- tie breaker when distance is the same (i.e. way is on boundary)
57 + 0.00001 * ST_Distance(feature, centroid)
59 isguess, postcode, centroid
60 FROM location_area_large_{{ partition }}
61 WHERE geometry && feature
62 AND is_relevant_geometry(ST_Relate(geometry, feature), ST_GeometryType(feature))
63 AND rank_address < maxrank
64 -- Postcodes currently still use rank_search to define for which
65 -- features they are relevant.
66 AND not (rank_address in (5, 11) and rank_search > maxrank)
67 GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
75 RAISE EXCEPTION 'Unknown partition %', in_partition;
78 LANGUAGE plpgsql STABLE;
81 CREATE OR REPLACE FUNCTION get_address_place(in_partition SMALLINT, feature GEOMETRY,
82 from_rank SMALLINT, to_rank SMALLINT,
83 extent FLOAT, token_info JSONB, key TEXT)
84 RETURNS nearfeaturecentr
87 r nearfeaturecentr%rowtype;
89 {% for partition in db.partitions %}
90 IF in_partition = {{ partition }} THEN
91 SELECT place_id, keywords, rank_address, rank_search,
92 min(ST_Distance(feature, centroid)) as distance,
93 isguess, postcode, centroid INTO r
94 FROM location_area_large_{{ partition }}
95 WHERE geometry && ST_Expand(feature, extent)
96 AND rank_address between from_rank and to_rank
97 AND token_matches_address(token_info, key, keywords)
98 GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
99 ORDER BY bool_or(ST_Intersects(geometry, feature)) DESC, distance LIMIT 1;
104 RAISE EXCEPTION 'Unknown partition %', in_partition;
107 LANGUAGE plpgsql STABLE;
110 create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$
114 IF in_rank_search <= 4 THEN
115 DELETE from location_area_country WHERE place_id = in_place_id;
119 {% for partition in db.partitions %}
120 IF in_partition = {{ partition }} THEN
121 DELETE from location_area_large_{{ partition }} WHERE place_id = in_place_id;
126 RAISE EXCEPTION 'Unknown partition %', in_partition;
133 create or replace function insertLocationAreaLarge(
134 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_keywords INTEGER[],
135 in_rank_search INTEGER, in_rank_address INTEGER, in_estimate BOOLEAN, postcode TEXT,
136 in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
139 IF in_rank_address = 0 THEN
143 IF in_rank_search <= 4 and not in_estimate THEN
144 INSERT INTO location_area_country (place_id, country_code, geometry)
145 values (in_place_id, in_country_code, in_geometry);
149 {% for partition in db.partitions %}
150 IF in_partition = {{ partition }} THEN
151 INSERT INTO location_area_large_{{ partition }} (partition, place_id, country_code, keywords, rank_search, rank_address, isguess, postcode, centroid, geometry)
152 values (in_partition, in_place_id, in_country_code, in_keywords, in_rank_search, in_rank_address, in_estimate, postcode, in_centroid, in_geometry);
157 RAISE EXCEPTION 'Unknown partition %', in_partition;
163 CREATE OR REPLACE FUNCTION getNearestNamedRoadPlaceId(in_partition INTEGER,
171 IF not token_has_addr_street(token_info) THEN
175 {% for partition in db.partitions %}
176 IF in_partition = {{ partition }} THEN
177 SELECT place_id FROM search_name_{{ partition }}
179 WHERE token_matches_street(token_info, name_vector)
180 AND centroid && ST_Expand(point, 0.015)
181 AND address_rank between 26 and 27
182 ORDER BY ST_Distance(centroid, point) ASC limit 1;
187 RAISE EXCEPTION 'Unknown partition %', in_partition;
190 LANGUAGE plpgsql STABLE;
192 CREATE OR REPLACE FUNCTION getNearestNamedPlacePlaceId(in_partition INTEGER,
200 IF not token_has_addr_place(token_info) THEN
204 {% for partition in db.partitions %}
205 IF in_partition = {{ partition }} THEN
208 FROM search_name_{{ partition }}
209 WHERE token_matches_place(token_info, name_vector)
210 AND centroid && ST_Expand(point, 0.04)
211 AND address_rank between 16 and 25
212 ORDER BY ST_Distance(centroid, point) ASC limit 1;
217 RAISE EXCEPTION 'Unknown partition %', in_partition;
220 LANGUAGE plpgsql STABLE;
222 create or replace function insertSearchName(
223 in_partition INTEGER, in_place_id BIGINT, in_name_vector INTEGER[],
224 in_rank_search INTEGER, in_rank_address INTEGER, in_geometry GEOMETRY)
225 RETURNS BOOLEAN AS $$
228 {% for partition in db.partitions %}
229 IF in_partition = {{ partition }} THEN
230 DELETE FROM search_name_{{ partition }} values WHERE place_id = in_place_id;
231 IF in_rank_address > 0 THEN
232 INSERT INTO search_name_{{ partition }} (place_id, address_rank, name_vector, centroid)
233 values (in_place_id, in_rank_address, in_name_vector, in_geometry);
239 RAISE EXCEPTION 'Unknown partition %', in_partition;
245 create or replace function deleteSearchName(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
248 {% for partition in db.partitions %}
249 IF in_partition = {{ partition }} THEN
250 DELETE from search_name_{{ partition }} WHERE place_id = in_place_id;
255 RAISE EXCEPTION 'Unknown partition %', in_partition;
262 create or replace function insertLocationRoad(
263 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
267 {% for partition in db.partitions %}
268 IF in_partition = {{ partition }} THEN
269 DELETE FROM location_road_{{ partition }} where place_id = in_place_id;
270 INSERT INTO location_road_{{ partition }} (partition, place_id, country_code, geometry)
271 values (in_partition, in_place_id, in_country_code, in_geometry);
276 RAISE EXCEPTION 'Unknown partition %', in_partition;
282 create or replace function deleteRoad(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
286 {% for partition in db.partitions %}
287 IF in_partition = {{ partition }} THEN
288 DELETE FROM location_road_{{ partition }} where place_id = in_place_id;
293 RAISE EXCEPTION 'Unknown partition %', in_partition;
300 CREATE OR REPLACE FUNCTION getNearestRoadPlaceId(in_partition INTEGER, point GEOMETRY)
305 search_diameter FLOAT;
308 {% for partition in db.partitions %}
309 IF in_partition = {{ partition }} THEN
310 search_diameter := 0.00005;
311 WHILE search_diameter < 0.1 LOOP
313 SELECT place_id FROM location_road_{{ partition }}
314 WHERE ST_DWithin(geometry, point, search_diameter)
315 ORDER BY ST_Distance(geometry, point) ASC limit 1
319 search_diameter := search_diameter * 2;
325 RAISE EXCEPTION 'Unknown partition %', in_partition;
328 LANGUAGE plpgsql STABLE;
330 CREATE OR REPLACE FUNCTION getNearestParallelRoadFeature(in_partition INTEGER,
336 search_diameter FLOAT;
342 IF ST_GeometryType(line) not in ('ST_LineString') THEN
346 p1 := ST_LineInterpolatePoint(line,0);
347 p2 := ST_LineInterpolatePoint(line,0.5);
348 p3 := ST_LineInterpolatePoint(line,1);
350 {% for partition in db.partitions %}
351 IF in_partition = {{ partition }} THEN
352 search_diameter := 0.0005;
353 WHILE search_diameter < 0.01 LOOP
355 SELECT place_id FROM location_road_{{ partition }}
356 WHERE ST_DWithin(line, geometry, search_diameter)
357 ORDER BY (ST_distance(geometry, p1)+
358 ST_distance(geometry, p2)+
359 ST_distance(geometry, p3)) ASC limit 1
363 search_diameter := search_diameter * 2;
369 RAISE EXCEPTION 'Unknown partition %', in_partition;
372 LANGUAGE plpgsql STABLE;