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 geoemtry
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 min(ST_Distance(feature_centroid, geometry)) as distance,
55 isguess, postcode, centroid
56 FROM location_area_large_{{ partition }}
57 WHERE geometry && feature
58 AND is_relevant_geometry(ST_Relate(geometry, feature), ST_GeometryType(feature))
59 AND rank_address < maxrank
60 -- Postcodes currently still use rank_search to define for which
61 -- features they are relevant.
62 AND not (rank_address in (5, 11) and rank_search > maxrank)
63 GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
71 RAISE EXCEPTION 'Unknown partition %', in_partition;
74 LANGUAGE plpgsql STABLE;
77 CREATE OR REPLACE FUNCTION get_address_place(in_partition SMALLINT, feature GEOMETRY,
78 from_rank SMALLINT, to_rank SMALLINT,
79 extent FLOAT, token_info JSONB, key TEXT)
80 RETURNS nearfeaturecentr
83 r nearfeaturecentr%rowtype;
85 {% for partition in db.partitions %}
86 IF in_partition = {{ partition }} THEN
87 SELECT place_id, keywords, rank_address, rank_search,
88 min(ST_Distance(feature, centroid)) as distance,
89 isguess, postcode, centroid INTO r
90 FROM location_area_large_{{ partition }}
91 WHERE geometry && ST_Expand(feature, extent)
92 AND rank_address between from_rank and to_rank
93 AND token_matches_address(token_info, key, keywords)
94 GROUP BY place_id, keywords, rank_address, rank_search, isguess, postcode, centroid
95 ORDER BY bool_or(ST_Intersects(geometry, feature)), distance LIMIT 1;
100 RAISE EXCEPTION 'Unknown partition %', in_partition;
103 LANGUAGE plpgsql STABLE;
106 create or replace function deleteLocationArea(in_partition INTEGER, in_place_id BIGINT, in_rank_search INTEGER) RETURNS BOOLEAN AS $$
110 IF in_rank_search <= 4 THEN
111 DELETE from location_area_country WHERE place_id = in_place_id;
115 {% for partition in db.partitions %}
116 IF in_partition = {{ partition }} THEN
117 DELETE from location_area_large_{{ partition }} WHERE place_id = in_place_id;
122 RAISE EXCEPTION 'Unknown partition %', in_partition;
129 create or replace function insertLocationAreaLarge(
130 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_keywords INTEGER[],
131 in_rank_search INTEGER, in_rank_address INTEGER, in_estimate BOOLEAN, postcode TEXT,
132 in_centroid GEOMETRY, in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
135 IF in_rank_address = 0 THEN
139 IF in_rank_search <= 4 and not in_estimate THEN
140 INSERT INTO location_area_country (place_id, country_code, geometry)
141 values (in_place_id, in_country_code, in_geometry);
145 {% for partition in db.partitions %}
146 IF in_partition = {{ partition }} THEN
147 INSERT INTO location_area_large_{{ partition }} (partition, place_id, country_code, keywords, rank_search, rank_address, isguess, postcode, centroid, geometry)
148 values (in_partition, in_place_id, in_country_code, in_keywords, in_rank_search, in_rank_address, in_estimate, postcode, in_centroid, in_geometry);
153 RAISE EXCEPTION 'Unknown partition %', in_partition;
159 CREATE OR REPLACE FUNCTION getNearestNamedRoadPlaceId(in_partition INTEGER,
167 IF not token_has_addr_street(token_info) THEN
171 {% for partition in db.partitions %}
172 IF in_partition = {{ partition }} THEN
173 SELECT place_id FROM search_name_{{ partition }}
175 WHERE token_matches_street(token_info, name_vector)
176 AND centroid && ST_Expand(point, 0.015)
177 AND address_rank between 26 and 27
178 ORDER BY ST_Distance(centroid, point) ASC limit 1;
183 RAISE EXCEPTION 'Unknown partition %', in_partition;
186 LANGUAGE plpgsql STABLE;
188 CREATE OR REPLACE FUNCTION getNearestNamedPlacePlaceId(in_partition INTEGER,
196 IF not token_has_addr_place(token_info) THEN
200 {% for partition in db.partitions %}
201 IF in_partition = {{ partition }} THEN
204 FROM search_name_{{ partition }}
205 WHERE token_matches_place(token_info, name_vector)
206 AND centroid && ST_Expand(point, 0.04)
207 AND address_rank between 16 and 25
208 ORDER BY ST_Distance(centroid, point) ASC limit 1;
213 RAISE EXCEPTION 'Unknown partition %', in_partition;
216 LANGUAGE plpgsql STABLE;
218 create or replace function insertSearchName(
219 in_partition INTEGER, in_place_id BIGINT, in_name_vector INTEGER[],
220 in_rank_search INTEGER, in_rank_address INTEGER, in_geometry GEOMETRY)
221 RETURNS BOOLEAN AS $$
224 {% for partition in db.partitions %}
225 IF in_partition = {{ partition }} THEN
226 DELETE FROM search_name_{{ partition }} values WHERE place_id = in_place_id;
227 IF in_rank_address > 0 THEN
228 INSERT INTO search_name_{{ partition }} (place_id, address_rank, name_vector, centroid)
229 values (in_place_id, in_rank_address, in_name_vector, in_geometry);
235 RAISE EXCEPTION 'Unknown partition %', in_partition;
241 create or replace function deleteSearchName(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
244 {% for partition in db.partitions %}
245 IF in_partition = {{ partition }} THEN
246 DELETE from search_name_{{ partition }} WHERE place_id = in_place_id;
251 RAISE EXCEPTION 'Unknown partition %', in_partition;
258 create or replace function insertLocationRoad(
259 in_partition INTEGER, in_place_id BIGINT, in_country_code VARCHAR(2), in_geometry GEOMETRY) RETURNS BOOLEAN AS $$
263 {% for partition in db.partitions %}
264 IF in_partition = {{ partition }} THEN
265 DELETE FROM location_road_{{ partition }} where place_id = in_place_id;
266 INSERT INTO location_road_{{ partition }} (partition, place_id, country_code, geometry)
267 values (in_partition, in_place_id, in_country_code, in_geometry);
272 RAISE EXCEPTION 'Unknown partition %', in_partition;
278 create or replace function deleteRoad(in_partition INTEGER, in_place_id BIGINT) RETURNS BOOLEAN AS $$
282 {% for partition in db.partitions %}
283 IF in_partition = {{ partition }} THEN
284 DELETE FROM location_road_{{ partition }} where place_id = in_place_id;
289 RAISE EXCEPTION 'Unknown partition %', in_partition;
296 CREATE OR REPLACE FUNCTION getNearestRoadPlaceId(in_partition INTEGER, point GEOMETRY)
301 search_diameter FLOAT;
304 {% for partition in db.partitions %}
305 IF in_partition = {{ partition }} THEN
306 search_diameter := 0.00005;
307 WHILE search_diameter < 0.1 LOOP
309 SELECT place_id FROM location_road_{{ partition }}
310 WHERE ST_DWithin(geometry, point, search_diameter)
311 ORDER BY ST_Distance(geometry, point) ASC limit 1
315 search_diameter := search_diameter * 2;
321 RAISE EXCEPTION 'Unknown partition %', in_partition;
324 LANGUAGE plpgsql STABLE;
326 CREATE OR REPLACE FUNCTION getNearestParallelRoadFeature(in_partition INTEGER,
332 search_diameter FLOAT;
338 IF ST_GeometryType(line) not in ('ST_LineString') THEN
342 p1 := ST_LineInterpolatePoint(line,0);
343 p2 := ST_LineInterpolatePoint(line,0.5);
344 p3 := ST_LineInterpolatePoint(line,1);
346 {% for partition in db.partitions %}
347 IF in_partition = {{ partition }} THEN
348 search_diameter := 0.0005;
349 WHILE search_diameter < 0.01 LOOP
351 SELECT place_id FROM location_road_{{ partition }}
352 WHERE ST_DWithin(line, geometry, search_diameter)
353 ORDER BY (ST_distance(geometry, p1)+
354 ST_distance(geometry, p2)+
355 ST_distance(geometry, p3)) ASC limit 1
359 search_diameter := search_diameter * 2;
365 RAISE EXCEPTION 'Unknown partition %', in_partition;
368 LANGUAGE plpgsql STABLE;