]> git.openstreetmap.org Git - nominatim.git/blob - nominatim/api/search/db_searches.py
Merge remote-tracking branch 'upstream/master'
[nominatim.git] / nominatim / api / search / db_searches.py
1 # SPDX-License-Identifier: GPL-3.0-or-later
2 #
3 # This file is part of Nominatim. (https://nominatim.org)
4 #
5 # Copyright (C) 2023 by the Nominatim developer community.
6 # For a full list of authors see the git log.
7 """
8 Implementation of the acutal database accesses for forward search.
9 """
10 from typing import List, Tuple, AsyncIterator, Dict, Any, Callable
11 import abc
12
13 import sqlalchemy as sa
14 from sqlalchemy.dialects.postgresql import ARRAY, array_agg
15
16 from nominatim.typing import SaFromClause, SaScalarSelect, SaColumn, \
17                              SaExpression, SaSelect, SaLambdaSelect, SaRow, SaBind
18 from nominatim.api.connection import SearchConnection
19 from nominatim.api.types import SearchDetails, DataLayer, GeometryFormat, Bbox
20 import nominatim.api.results as nres
21 from nominatim.api.search.db_search_fields import SearchData, WeightedCategories
22 from nominatim.db.sqlalchemy_types import Geometry
23
24 #pylint: disable=singleton-comparison,not-callable
25 #pylint: disable=too-many-branches,too-many-arguments,too-many-locals,too-many-statements
26
27 def no_index(expr: SaColumn) -> SaColumn:
28     """ Wrap the given expression, so that the query planner will
29         refrain from using the expression for index lookup.
30     """
31     return sa.func.coalesce(sa.null(), expr) # pylint: disable=not-callable
32
33
34 def _details_to_bind_params(details: SearchDetails) -> Dict[str, Any]:
35     """ Create a dictionary from search parameters that can be used
36         as bind parameter for SQL execute.
37     """
38     return {'limit': details.max_results,
39             'min_rank': details.min_rank,
40             'max_rank': details.max_rank,
41             'viewbox': details.viewbox,
42             'viewbox2': details.viewbox_x2,
43             'near': details.near,
44             'near_radius': details.near_radius,
45             'excluded': details.excluded,
46             'countries': details.countries}
47
48
49 LIMIT_PARAM: SaBind = sa.bindparam('limit')
50 MIN_RANK_PARAM: SaBind = sa.bindparam('min_rank')
51 MAX_RANK_PARAM: SaBind = sa.bindparam('max_rank')
52 VIEWBOX_PARAM: SaBind = sa.bindparam('viewbox', type_=Geometry)
53 VIEWBOX2_PARAM: SaBind = sa.bindparam('viewbox2', type_=Geometry)
54 NEAR_PARAM: SaBind = sa.bindparam('near', type_=Geometry)
55 NEAR_RADIUS_PARAM: SaBind = sa.bindparam('near_radius')
56 COUNTRIES_PARAM: SaBind = sa.bindparam('countries')
57
58 def _within_near(t: SaFromClause) -> Callable[[], SaExpression]:
59     return lambda: t.c.geometry.ST_DWithin(NEAR_PARAM, NEAR_RADIUS_PARAM)
60
61 def _exclude_places(t: SaFromClause) -> Callable[[], SaExpression]:
62     return lambda: t.c.place_id.not_in(sa.bindparam('excluded'))
63
64 def _select_placex(t: SaFromClause) -> SaSelect:
65     return sa.select(t.c.place_id, t.c.osm_type, t.c.osm_id, t.c.name,
66                      t.c.class_, t.c.type,
67                      t.c.address, t.c.extratags,
68                      t.c.housenumber, t.c.postcode, t.c.country_code,
69                      t.c.importance, t.c.wikipedia,
70                      t.c.parent_place_id, t.c.rank_address, t.c.rank_search,
71                      t.c.linked_place_id, t.c.admin_level,
72                      t.c.centroid,
73                      t.c.geometry.ST_Expand(0).label('bbox'))
74
75
76 def _add_geometry_columns(sql: SaLambdaSelect, col: SaColumn, details: SearchDetails) -> SaSelect:
77     out = []
78
79     if details.geometry_simplification > 0.0:
80         col = sa.func.ST_SimplifyPreserveTopology(col, details.geometry_simplification)
81
82     if details.geometry_output & GeometryFormat.GEOJSON:
83         out.append(sa.func.ST_AsGeoJSON(col, 7).label('geometry_geojson'))
84     if details.geometry_output & GeometryFormat.TEXT:
85         out.append(sa.func.ST_AsText(col).label('geometry_text'))
86     if details.geometry_output & GeometryFormat.KML:
87         out.append(sa.func.ST_AsKML(col, 7).label('geometry_kml'))
88     if details.geometry_output & GeometryFormat.SVG:
89         out.append(sa.func.ST_AsSVG(col, 0, 7).label('geometry_svg'))
90
91     return sql.add_columns(*out)
92
93
94 def _make_interpolation_subquery(table: SaFromClause, inner: SaFromClause,
95                                  numerals: List[int], details: SearchDetails) -> SaScalarSelect:
96     all_ids = array_agg(table.c.place_id) # type: ignore[no-untyped-call]
97     sql = sa.select(all_ids).where(table.c.parent_place_id == inner.c.place_id)
98
99     if len(numerals) == 1:
100         sql = sql.where(sa.between(numerals[0], table.c.startnumber, table.c.endnumber))\
101                  .where((numerals[0] - table.c.startnumber) % table.c.step == 0)
102     else:
103         sql = sql.where(sa.or_(
104                 *(sa.and_(sa.between(n, table.c.startnumber, table.c.endnumber),
105                           (n - table.c.startnumber) % table.c.step == 0)
106                   for n in numerals)))
107
108     if details.excluded:
109         sql = sql.where(_exclude_places(table))
110
111     return sql.scalar_subquery()
112
113
114 def _filter_by_layer(table: SaFromClause, layers: DataLayer) -> SaColumn:
115     orexpr: List[SaExpression] = []
116     if layers & DataLayer.ADDRESS and layers & DataLayer.POI:
117         orexpr.append(no_index(table.c.rank_address).between(1, 30))
118     elif layers & DataLayer.ADDRESS:
119         orexpr.append(no_index(table.c.rank_address).between(1, 29))
120         orexpr.append(sa.and_(no_index(table.c.rank_address) == 30,
121                               sa.or_(table.c.housenumber != None,
122                                      table.c.address.has_key('addr:housename'))))
123     elif layers & DataLayer.POI:
124         orexpr.append(sa.and_(no_index(table.c.rank_address) == 30,
125                               table.c.class_.not_in(('place', 'building'))))
126
127     if layers & DataLayer.MANMADE:
128         exclude = []
129         if not layers & DataLayer.RAILWAY:
130             exclude.append('railway')
131         if not layers & DataLayer.NATURAL:
132             exclude.extend(('natural', 'water', 'waterway'))
133         orexpr.append(sa.and_(table.c.class_.not_in(tuple(exclude)),
134                               no_index(table.c.rank_address) == 0))
135     else:
136         include = []
137         if layers & DataLayer.RAILWAY:
138             include.append('railway')
139         if layers & DataLayer.NATURAL:
140             include.extend(('natural', 'water', 'waterway'))
141         orexpr.append(sa.and_(table.c.class_.in_(tuple(include)),
142                               no_index(table.c.rank_address) == 0))
143
144     if len(orexpr) == 1:
145         return orexpr[0]
146
147     return sa.or_(*orexpr)
148
149
150 def _interpolated_position(table: SaFromClause, nr: SaColumn) -> SaColumn:
151     pos = sa.cast(nr - table.c.startnumber, sa.Float) / (table.c.endnumber - table.c.startnumber)
152     return sa.case(
153             (table.c.endnumber == table.c.startnumber, table.c.linegeo.ST_Centroid()),
154             else_=table.c.linegeo.ST_LineInterpolatePoint(pos)).label('centroid')
155
156
157 async def _get_placex_housenumbers(conn: SearchConnection,
158                                    place_ids: List[int],
159                                    details: SearchDetails) -> AsyncIterator[nres.SearchResult]:
160     t = conn.t.placex
161     sql = _select_placex(t).where(t.c.place_id.in_(place_ids))
162
163     if details.geometry_output:
164         sql = _add_geometry_columns(sql, t.c.geometry, details)
165
166     for row in await conn.execute(sql):
167         result = nres.create_from_placex_row(row, nres.SearchResult)
168         assert result
169         result.bbox = Bbox.from_wkb(row.bbox)
170         yield result
171
172
173 async def _get_osmline(conn: SearchConnection, place_ids: List[int],
174                        numerals: List[int],
175                        details: SearchDetails) -> AsyncIterator[nres.SearchResult]:
176     t = conn.t.osmline
177     values = sa.values(sa.Column('nr', sa.Integer()), name='housenumber')\
178                .data([(n,) for n in numerals])
179     sql = sa.select(t.c.place_id, t.c.osm_id,
180                     t.c.parent_place_id, t.c.address,
181                     values.c.nr.label('housenumber'),
182                     _interpolated_position(t, values.c.nr),
183                     t.c.postcode, t.c.country_code)\
184             .where(t.c.place_id.in_(place_ids))\
185             .join(values, values.c.nr.between(t.c.startnumber, t.c.endnumber))
186
187     if details.geometry_output:
188         sub = sql.subquery()
189         sql = _add_geometry_columns(sa.select(sub), sub.c.centroid, details)
190
191     for row in await conn.execute(sql):
192         result = nres.create_from_osmline_row(row, nres.SearchResult)
193         assert result
194         yield result
195
196
197 async def _get_tiger(conn: SearchConnection, place_ids: List[int],
198                      numerals: List[int], osm_id: int,
199                      details: SearchDetails) -> AsyncIterator[nres.SearchResult]:
200     t = conn.t.tiger
201     values = sa.values(sa.Column('nr', sa.Integer()), name='housenumber')\
202                .data([(n,) for n in numerals])
203     sql = sa.select(t.c.place_id, t.c.parent_place_id,
204                     sa.literal('W').label('osm_type'),
205                     sa.literal(osm_id).label('osm_id'),
206                     values.c.nr.label('housenumber'),
207                     _interpolated_position(t, values.c.nr),
208                     t.c.postcode)\
209             .where(t.c.place_id.in_(place_ids))\
210             .join(values, values.c.nr.between(t.c.startnumber, t.c.endnumber))
211
212     if details.geometry_output:
213         sub = sql.subquery()
214         sql = _add_geometry_columns(sa.select(sub), sub.c.centroid, details)
215
216     for row in await conn.execute(sql):
217         result = nres.create_from_tiger_row(row, nres.SearchResult)
218         assert result
219         yield result
220
221
222 class AbstractSearch(abc.ABC):
223     """ Encapuslation of a single lookup in the database.
224     """
225
226     def __init__(self, penalty: float) -> None:
227         self.penalty = penalty
228
229     @abc.abstractmethod
230     async def lookup(self, conn: SearchConnection,
231                      details: SearchDetails) -> nres.SearchResults:
232         """ Find results for the search in the database.
233         """
234
235
236 class NearSearch(AbstractSearch):
237     """ Category search of a place type near the result of another search.
238     """
239     def __init__(self, penalty: float, categories: WeightedCategories,
240                  search: AbstractSearch) -> None:
241         super().__init__(penalty)
242         self.search = search
243         self.categories = categories
244
245
246     async def lookup(self, conn: SearchConnection,
247                      details: SearchDetails) -> nres.SearchResults:
248         """ Find results for the search in the database.
249         """
250         results = nres.SearchResults()
251         base = await self.search.lookup(conn, details)
252
253         if not base:
254             return results
255
256         base.sort(key=lambda r: (r.accuracy, r.rank_search))
257         max_accuracy = base[0].accuracy + 0.5
258         base = nres.SearchResults(r for r in base if r.source_table == nres.SourceTable.PLACEX
259                                                      and r.accuracy <= max_accuracy
260                                                      and r.bbox and r.bbox.area < 20)
261
262         if base:
263             baseids = [b.place_id for b in base[:5] if b.place_id]
264
265             for category, penalty in self.categories:
266                 await self.lookup_category(results, conn, baseids, category, penalty, details)
267                 if len(results) >= details.max_results:
268                     break
269
270         return results
271
272
273     async def lookup_category(self, results: nres.SearchResults,
274                               conn: SearchConnection, ids: List[int],
275                               category: Tuple[str, str], penalty: float,
276                               details: SearchDetails) -> None:
277         """ Find places of the given category near the list of
278             place ids and add the results to 'results'.
279         """
280         table = await conn.get_class_table(*category)
281
282         t = conn.t.placex
283         tgeom = conn.t.placex.alias('pgeom')
284
285         sql = _select_placex(t).where(tgeom.c.place_id.in_(ids))\
286                                .where(t.c.class_ == category[0])\
287                                .where(t.c.type == category[1])
288
289         if table is None:
290             # No classtype table available, do a simplified lookup in placex.
291             sql = sql.join(tgeom, t.c.geometry.ST_DWithin(tgeom.c.centroid, 0.01))\
292                      .order_by(tgeom.c.centroid.ST_Distance(t.c.centroid))
293         else:
294             # Use classtype table. We can afford to use a larger
295             # radius for the lookup.
296             sql = sql.join(table, t.c.place_id == table.c.place_id)\
297                      .join(tgeom,
298                            table.c.centroid.ST_CoveredBy(
299                                sa.case((sa.and_(tgeom.c.rank_address > 9,
300                                                 tgeom.c.geometry.is_area()),
301                                         tgeom.c.geometry),
302                                        else_ = tgeom.c.centroid.ST_Expand(0.05))))\
303                      .order_by(tgeom.c.centroid.ST_Distance(table.c.centroid))
304
305         sql = sql.where(no_index(t.c.rank_address).between(MIN_RANK_PARAM, MAX_RANK_PARAM))
306         if details.countries:
307             sql = sql.where(t.c.country_code.in_(COUNTRIES_PARAM))
308         if details.excluded:
309             sql = sql.where(_exclude_places(t))
310         if details.layers is not None:
311             sql = sql.where(_filter_by_layer(t, details.layers))
312
313         sql = sql.limit(LIMIT_PARAM)
314         for row in await conn.execute(sql, _details_to_bind_params(details)):
315             result = nres.create_from_placex_row(row, nres.SearchResult)
316             assert result
317             result.accuracy = self.penalty + penalty
318             result.bbox = Bbox.from_wkb(row.bbox)
319             results.append(result)
320
321
322
323 class PoiSearch(AbstractSearch):
324     """ Category search in a geographic area.
325     """
326     def __init__(self, sdata: SearchData) -> None:
327         super().__init__(sdata.penalty)
328         self.qualifiers = sdata.qualifiers
329         self.countries = sdata.countries
330
331
332     async def lookup(self, conn: SearchConnection,
333                      details: SearchDetails) -> nres.SearchResults:
334         """ Find results for the search in the database.
335         """
336         bind_params = _details_to_bind_params(details)
337         t = conn.t.placex
338
339         rows: List[SaRow] = []
340
341         if details.near and details.near_radius is not None and details.near_radius < 0.2:
342             # simply search in placex table
343             def _base_query() -> SaSelect:
344                 return _select_placex(t) \
345                            .where(t.c.linked_place_id == None) \
346                            .where(t.c.geometry.ST_DWithin(NEAR_PARAM, NEAR_RADIUS_PARAM)) \
347                            .order_by(t.c.centroid.ST_Distance(NEAR_PARAM)) \
348                            .limit(LIMIT_PARAM)
349
350             classtype = self.qualifiers.values
351             if len(classtype) == 1:
352                 cclass, ctype = classtype[0]
353                 sql: SaLambdaSelect = sa.lambda_stmt(lambda: _base_query()
354                                                  .where(t.c.class_ == cclass)
355                                                  .where(t.c.type == ctype))
356             else:
357                 sql = _base_query().where(sa.or_(*(sa.and_(t.c.class_ == cls, t.c.type == typ)
358                                                    for cls, typ in classtype)))
359
360             if self.countries:
361                 sql = sql.where(t.c.country_code.in_(self.countries.values))
362
363             if details.viewbox is not None and details.bounded_viewbox:
364                 sql = sql.where(t.c.geometry.intersects(VIEWBOX_PARAM))
365
366             rows.extend(await conn.execute(sql, bind_params))
367         else:
368             # use the class type tables
369             for category in self.qualifiers.values:
370                 table = await conn.get_class_table(*category)
371                 if table is not None:
372                     sql = _select_placex(t)\
373                                .join(table, t.c.place_id == table.c.place_id)\
374                                .where(t.c.class_ == category[0])\
375                                .where(t.c.type == category[1])
376
377                     if details.viewbox is not None and details.bounded_viewbox:
378                         sql = sql.where(table.c.centroid.intersects(VIEWBOX_PARAM))
379
380                     if details.near and details.near_radius is not None:
381                         sql = sql.order_by(table.c.centroid.ST_Distance(NEAR_PARAM))\
382                                  .where(table.c.centroid.ST_DWithin(NEAR_PARAM,
383                                                                     NEAR_RADIUS_PARAM))
384
385                     if self.countries:
386                         sql = sql.where(t.c.country_code.in_(self.countries.values))
387
388                     sql = sql.limit(LIMIT_PARAM)
389                     rows.extend(await conn.execute(sql, bind_params))
390
391         results = nres.SearchResults()
392         for row in rows:
393             result = nres.create_from_placex_row(row, nres.SearchResult)
394             assert result
395             result.accuracy = self.penalty + self.qualifiers.get_penalty((row.class_, row.type))
396             result.bbox = Bbox.from_wkb(row.bbox)
397             results.append(result)
398
399         return results
400
401
402 class CountrySearch(AbstractSearch):
403     """ Search for a country name or country code.
404     """
405     def __init__(self, sdata: SearchData) -> None:
406         super().__init__(sdata.penalty)
407         self.countries = sdata.countries
408
409
410     async def lookup(self, conn: SearchConnection,
411                      details: SearchDetails) -> nres.SearchResults:
412         """ Find results for the search in the database.
413         """
414         t = conn.t.placex
415
416         ccodes = self.countries.values
417         sql = _select_placex(t)\
418                 .where(t.c.country_code.in_(ccodes))\
419                 .where(t.c.rank_address == 4)
420
421         if details.geometry_output:
422             sql = _add_geometry_columns(sql, t.c.geometry, details)
423
424         if details.excluded:
425             sql = sql.where(_exclude_places(t))
426
427         if details.viewbox is not None and details.bounded_viewbox:
428             sql = sql.where(lambda: t.c.geometry.intersects(VIEWBOX_PARAM))
429
430         if details.near is not None and details.near_radius is not None:
431             sql = sql.where(_within_near(t))
432
433         results = nres.SearchResults()
434         for row in await conn.execute(sql, _details_to_bind_params(details)):
435             result = nres.create_from_placex_row(row, nres.SearchResult)
436             assert result
437             result.accuracy = self.penalty + self.countries.get_penalty(row.country_code, 5.0)
438             result.bbox = Bbox.from_wkb(row.bbox)
439             results.append(result)
440
441         return results or await self.lookup_in_country_table(conn, details)
442
443
444     async def lookup_in_country_table(self, conn: SearchConnection,
445                                       details: SearchDetails) -> nres.SearchResults:
446         """ Look up the country in the fallback country tables.
447         """
448         # Avoid the fallback search when this is a more search. Country results
449         # usually are in the first batch of results and it is not possible
450         # to exclude these fallbacks.
451         if details.excluded:
452             return nres.SearchResults()
453
454         t = conn.t.country_name
455         tgrid = conn.t.country_grid
456
457         sql = sa.select(tgrid.c.country_code,
458                         tgrid.c.geometry.ST_Centroid().ST_Collect().ST_Centroid()
459                               .label('centroid'),
460                         tgrid.c.geometry.ST_Collect().ST_Expand(0).label('bbox'))\
461                 .where(tgrid.c.country_code.in_(self.countries.values))\
462                 .group_by(tgrid.c.country_code)
463
464         if details.viewbox is not None and details.bounded_viewbox:
465             sql = sql.where(tgrid.c.geometry.intersects(VIEWBOX_PARAM))
466         if details.near is not None and details.near_radius is not None:
467             sql = sql.where(_within_near(tgrid))
468
469         sub = sql.subquery('grid')
470
471         sql = sa.select(t.c.country_code,
472                         (t.c.name
473                          + sa.func.coalesce(t.c.derived_name,
474                                             sa.cast('', type_=conn.t.types.Composite))
475                         ).label('name'),
476                         sub.c.centroid, sub.c.bbox)\
477                 .join(sub, t.c.country_code == sub.c.country_code)
478
479         if details.geometry_output:
480             sql = _add_geometry_columns(sql, sub.c.centroid, details)
481
482         results = nres.SearchResults()
483         for row in await conn.execute(sql, _details_to_bind_params(details)):
484             result = nres.create_from_country_row(row, nres.SearchResult)
485             assert result
486             result.bbox = Bbox.from_wkb(row.bbox)
487             result.accuracy = self.penalty + self.countries.get_penalty(row.country_code, 5.0)
488             results.append(result)
489
490         return results
491
492
493
494 class PostcodeSearch(AbstractSearch):
495     """ Search for a postcode.
496     """
497     def __init__(self, extra_penalty: float, sdata: SearchData) -> None:
498         super().__init__(sdata.penalty + extra_penalty)
499         self.countries = sdata.countries
500         self.postcodes = sdata.postcodes
501         self.lookups = sdata.lookups
502         self.rankings = sdata.rankings
503
504
505     async def lookup(self, conn: SearchConnection,
506                      details: SearchDetails) -> nres.SearchResults:
507         """ Find results for the search in the database.
508         """
509         t = conn.t.postcode
510         pcs = self.postcodes.values
511
512         sql = sa.select(t.c.place_id, t.c.parent_place_id,
513                         t.c.rank_search, t.c.rank_address,
514                         t.c.postcode, t.c.country_code,
515                         t.c.geometry.label('centroid'))\
516                 .where(t.c.postcode.in_(pcs))
517
518         if details.geometry_output:
519             sql = _add_geometry_columns(sql, t.c.geometry, details)
520
521         penalty: SaExpression = sa.literal(self.penalty)
522
523         if details.viewbox is not None:
524             if details.bounded_viewbox:
525                 sql = sql.where(t.c.geometry.intersects(VIEWBOX_PARAM))
526             else:
527                 penalty += sa.case((t.c.geometry.intersects(VIEWBOX_PARAM), 0.0),
528                                    (t.c.geometry.intersects(VIEWBOX2_PARAM), 0.5),
529                                    else_=1.0)
530
531         if details.near is not None:
532             if details.near_radius is not None:
533                 sql = sql.where(_within_near(t))
534             sql = sql.order_by(t.c.geometry.ST_Distance(NEAR_PARAM))
535
536         if self.countries:
537             sql = sql.where(t.c.country_code.in_(self.countries.values))
538
539         if details.excluded:
540             sql = sql.where(_exclude_places(t))
541
542         if self.lookups:
543             assert len(self.lookups) == 1
544             assert self.lookups[0].lookup_type == 'restrict'
545             tsearch = conn.t.search_name
546             sql = sql.where(tsearch.c.place_id == t.c.parent_place_id)\
547                      .where(sa.func.array_cat(tsearch.c.name_vector,
548                                               tsearch.c.nameaddress_vector,
549                                               type_=ARRAY(sa.Integer))
550                                     .contains(self.lookups[0].tokens))
551
552         for ranking in self.rankings:
553             penalty += ranking.sql_penalty(conn.t.search_name)
554         penalty += sa.case(*((t.c.postcode == v, p) for v, p in self.postcodes),
555                        else_=1.0)
556
557
558         sql = sql.add_columns(penalty.label('accuracy'))
559         sql = sql.order_by('accuracy').limit(LIMIT_PARAM)
560
561         results = nres.SearchResults()
562         for row in await conn.execute(sql, _details_to_bind_params(details)):
563             result = nres.create_from_postcode_row(row, nres.SearchResult)
564             assert result
565             result.accuracy = row.accuracy
566             results.append(result)
567
568         return results
569
570
571
572 class PlaceSearch(AbstractSearch):
573     """ Generic search for an address or named place.
574     """
575     def __init__(self, extra_penalty: float, sdata: SearchData, expected_count: int) -> None:
576         super().__init__(sdata.penalty + extra_penalty)
577         self.countries = sdata.countries
578         self.postcodes = sdata.postcodes
579         self.housenumbers = sdata.housenumbers
580         self.qualifiers = sdata.qualifiers
581         self.lookups = sdata.lookups
582         self.rankings = sdata.rankings
583         self.expected_count = expected_count
584
585
586     async def lookup(self, conn: SearchConnection,
587                      details: SearchDetails) -> nres.SearchResults:
588         """ Find results for the search in the database.
589         """
590         t = conn.t.placex
591         tsearch = conn.t.search_name
592
593         sql: SaLambdaSelect = sa.lambda_stmt(lambda:
594                   sa.select(t.c.place_id, t.c.osm_type, t.c.osm_id, t.c.name,
595                             t.c.class_, t.c.type,
596                             t.c.address, t.c.extratags, t.c.admin_level,
597                             t.c.housenumber, t.c.postcode, t.c.country_code,
598                             t.c.wikipedia,
599                             t.c.parent_place_id, t.c.rank_address, t.c.rank_search,
600                             t.c.centroid,
601                             t.c.geometry.ST_Expand(0).label('bbox'))
602                    .where(t.c.place_id == tsearch.c.place_id))
603
604
605         if details.geometry_output:
606             sql = _add_geometry_columns(sql, t.c.geometry, details)
607
608         penalty: SaExpression = sa.literal(self.penalty)
609         for ranking in self.rankings:
610             penalty += ranking.sql_penalty(tsearch)
611
612         for lookup in self.lookups:
613             sql = sql.where(lookup.sql_condition(tsearch))
614
615         if self.countries:
616             sql = sql.where(tsearch.c.country_code.in_(self.countries.values))
617
618         if self.postcodes:
619             # if a postcode is given, don't search for state or country level objects
620             sql = sql.where(tsearch.c.address_rank > 9)
621             tpc = conn.t.postcode
622             pcs = self.postcodes.values
623             if self.expected_count > 1000:
624                 # Many results expected. Restrict by postcode.
625                 sql = sql.where(sa.select(tpc.c.postcode)
626                                   .where(tpc.c.postcode.in_(pcs))
627                                   .where(tsearch.c.centroid.ST_DWithin(tpc.c.geometry, 0.12))
628                                   .exists())
629
630             # Less results, only have a preference for close postcodes
631             pc_near = sa.select(sa.func.min(tpc.c.geometry.ST_Distance(tsearch.c.centroid)))\
632                       .where(tpc.c.postcode.in_(pcs))\
633                       .scalar_subquery()
634             penalty += sa.case((t.c.postcode.in_(pcs), 0.0),
635                                else_=sa.func.coalesce(pc_near, 2.0))
636
637         if details.viewbox is not None:
638             if details.bounded_viewbox:
639                 if details.viewbox.area < 0.2:
640                     sql = sql.where(tsearch.c.centroid.intersects(VIEWBOX_PARAM))
641                 else:
642                     sql = sql.where(tsearch.c.centroid.ST_Intersects_no_index(VIEWBOX_PARAM))
643             elif self.expected_count >= 10000:
644                 if details.viewbox.area < 0.5:
645                     sql = sql.where(tsearch.c.centroid.intersects(VIEWBOX2_PARAM))
646                 else:
647                     sql = sql.where(tsearch.c.centroid.ST_Intersects_no_index(VIEWBOX2_PARAM))
648             else:
649                 penalty += sa.case((t.c.geometry.intersects(VIEWBOX_PARAM), 0.0),
650                                    (t.c.geometry.intersects(VIEWBOX2_PARAM), 0.5),
651                                    else_=1.0)
652
653         if details.near is not None:
654             if details.near_radius is not None:
655                 if details.near_radius < 0.1:
656                     sql = sql.where(tsearch.c.centroid.ST_DWithin(NEAR_PARAM, NEAR_RADIUS_PARAM))
657                 else:
658                     sql = sql.where(tsearch.c.centroid.ST_DWithin_no_index(NEAR_PARAM,
659                                                                            NEAR_RADIUS_PARAM))
660             sql = sql.add_columns((-tsearch.c.centroid.ST_Distance(NEAR_PARAM))
661                                       .label('importance'))
662             sql = sql.order_by(sa.desc(sa.text('importance')))
663         else:
664             if self.expected_count < 10000\
665                or (details.viewbox is not None and details.viewbox.area < 0.5):
666                 sql = sql.order_by(
667                         penalty - sa.case((tsearch.c.importance > 0, tsearch.c.importance),
668                                     else_=0.75001-(sa.cast(tsearch.c.search_rank, sa.Float())/40)))
669             sql = sql.add_columns(t.c.importance)
670
671
672         sql = sql.add_columns(penalty.label('accuracy'))
673
674         if self.expected_count < 10000:
675             sql = sql.order_by(sa.text('accuracy'))
676
677         if self.housenumbers:
678             hnr_regexp = f"\\m({'|'.join(self.housenumbers.values)})\\M"
679             sql = sql.where(tsearch.c.address_rank.between(16, 30))\
680                      .where(sa.or_(tsearch.c.address_rank < 30,
681                                    t.c.housenumber.op('~*')(hnr_regexp)))
682
683             # Cross check for housenumbers, need to do that on a rather large
684             # set. Worst case there are 40.000 main streets in OSM.
685             inner = sql.limit(10000).subquery()
686
687             # Housenumbers from placex
688             thnr = conn.t.placex.alias('hnr')
689             pid_list = array_agg(thnr.c.place_id) # type: ignore[no-untyped-call]
690             place_sql = sa.select(pid_list)\
691                           .where(thnr.c.parent_place_id == inner.c.place_id)\
692                           .where(thnr.c.housenumber.op('~*')(hnr_regexp))\
693                           .where(thnr.c.linked_place_id == None)\
694                           .where(thnr.c.indexed_status == 0)
695
696             if details.excluded:
697                 place_sql = place_sql.where(thnr.c.place_id.not_in(sa.bindparam('excluded')))
698             if self.qualifiers:
699                 place_sql = place_sql.where(self.qualifiers.sql_restrict(thnr))
700
701             numerals = [int(n) for n in self.housenumbers.values
702                         if n.isdigit() and len(n) < 8]
703             interpol_sql: SaColumn
704             tiger_sql: SaColumn
705             if numerals and \
706                (not self.qualifiers or ('place', 'house') in self.qualifiers.values):
707                 # Housenumbers from interpolations
708                 interpol_sql = _make_interpolation_subquery(conn.t.osmline, inner,
709                                                             numerals, details)
710                 # Housenumbers from Tiger
711                 tiger_sql = sa.case((inner.c.country_code == 'us',
712                                      _make_interpolation_subquery(conn.t.tiger, inner,
713                                                                   numerals, details)
714                                     ), else_=None)
715             else:
716                 interpol_sql = sa.null()
717                 tiger_sql = sa.null()
718
719             unsort = sa.select(inner, place_sql.scalar_subquery().label('placex_hnr'),
720                                interpol_sql.label('interpol_hnr'),
721                                tiger_sql.label('tiger_hnr')).subquery('unsort')
722             sql = sa.select(unsort)\
723                     .order_by(sa.case((unsort.c.placex_hnr != None, 1),
724                                       (unsort.c.interpol_hnr != None, 2),
725                                       (unsort.c.tiger_hnr != None, 3),
726                                       else_=4),
727                               unsort.c.accuracy)
728         else:
729             sql = sql.where(t.c.linked_place_id == None)\
730                      .where(t.c.indexed_status == 0)
731             if self.qualifiers:
732                 sql = sql.where(self.qualifiers.sql_restrict(t))
733             if details.excluded:
734                 sql = sql.where(_exclude_places(tsearch))
735             if details.min_rank > 0:
736                 sql = sql.where(sa.or_(tsearch.c.address_rank >= MIN_RANK_PARAM,
737                                        tsearch.c.search_rank >= MIN_RANK_PARAM))
738             if details.max_rank < 30:
739                 sql = sql.where(sa.or_(tsearch.c.address_rank <= MAX_RANK_PARAM,
740                                        tsearch.c.search_rank <= MAX_RANK_PARAM))
741             if details.layers is not None:
742                 sql = sql.where(_filter_by_layer(t, details.layers))
743
744         sql = sql.limit(LIMIT_PARAM)
745
746         results = nres.SearchResults()
747         for row in await conn.execute(sql, _details_to_bind_params(details)):
748             result = nres.create_from_placex_row(row, nres.SearchResult)
749             assert result
750             result.bbox = Bbox.from_wkb(row.bbox)
751             result.accuracy = row.accuracy
752             if not details.excluded or not result.place_id in details.excluded:
753                 results.append(result)
754
755             if self.housenumbers and row.rank_address < 30:
756                 if row.placex_hnr:
757                     subs = _get_placex_housenumbers(conn, row.placex_hnr, details)
758                 elif row.interpol_hnr:
759                     subs = _get_osmline(conn, row.interpol_hnr, numerals, details)
760                 elif row.tiger_hnr:
761                     subs = _get_tiger(conn, row.tiger_hnr, numerals, row.osm_id, details)
762                 else:
763                     subs = None
764
765                 if subs is not None:
766                     async for sub in subs:
767                         assert sub.housenumber
768                         sub.accuracy = result.accuracy
769                         if not any(nr in self.housenumbers.values
770                                    for nr in sub.housenumber.split(';')):
771                             sub.accuracy += 0.6
772                         results.append(sub)
773
774                 result.accuracy += 1.0 # penalty for missing housenumber
775
776         return results