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 Functions for database migration to newer software versions.
10 from typing import List, Tuple, Callable, Any
13 from psycopg2 import sql as pysql
15 from nominatim.config import Configuration
16 from nominatim.db import properties
17 from nominatim.db.connection import connect, Connection
18 from nominatim.version import NominatimVersion, NOMINATIM_VERSION, parse_version
19 from nominatim.tools import refresh
20 from nominatim.tokenizer import factory as tokenizer_factory
21 from nominatim.errors import UsageError
23 LOG = logging.getLogger()
25 _MIGRATION_FUNCTIONS : List[Tuple[NominatimVersion, Callable[..., None]]] = []
27 def migrate(config: Configuration, paths: Any) -> int:
28 """ Check for the current database version and execute migrations,
31 with connect(config.get_libpq_dsn()) as conn:
32 if conn.table_exists('nominatim_properties'):
33 db_version_str = properties.get_property(conn, 'database_version')
37 if db_version_str is not None:
38 db_version = parse_version(db_version_str)
40 if db_version == NOMINATIM_VERSION:
41 LOG.warning("Database already at latest version (%s)", db_version_str)
44 LOG.info("Detected database version: %s", db_version_str)
46 db_version = _guess_version(conn)
49 for version, func in _MIGRATION_FUNCTIONS:
50 if db_version < version or \
51 (db_version == (3, 5, 0, 99) and version == (3, 5, 0, 99)):
52 title = func.__doc__ or ''
53 LOG.warning("Running: %s (%s)", title.split('\n', 1)[0], version)
54 kwargs = dict(conn=conn, config=config, paths=paths)
58 LOG.warning('Updating SQL functions.')
59 refresh.create_functions(conn, config)
60 tokenizer = tokenizer_factory.get_tokenizer_for_db(config)
61 tokenizer.update_sql_functions(config)
63 properties.set_property(conn, 'database_version', str(NOMINATIM_VERSION))
70 def _guess_version(conn: Connection) -> NominatimVersion:
71 """ Guess a database version when there is no property table yet.
72 Only migrations for 3.6 and later are supported, so bail out
73 when the version seems older.
75 with conn.cursor() as cur:
76 # In version 3.6, the country_name table was updated. Check for that.
77 cnt = cur.scalar("""SELECT count(*) FROM
78 (SELECT svals(name) FROM country_name
79 WHERE country_code = 'gb')x;
82 LOG.fatal('It looks like your database was imported with a version '
83 'prior to 3.6.0. Automatic migration not possible.')
84 raise UsageError('Migration not possible.')
86 return NominatimVersion(3, 5, 0, 99)
90 def _migration(major: int, minor: int, patch: int = 0,
91 dbpatch: int = 0) -> Callable[[Callable[..., None]], Callable[..., None]]:
92 """ Decorator for a single migration step. The parameters describe the
93 version after which the migration is applicable, i.e before changing
94 from the given version to the next, the migration is required.
96 All migrations are run in the order in which they are defined in this
97 file. Do not run global SQL scripts for migrations as you cannot be sure
98 that these scripts do the same in later versions.
100 Functions will always be reimported in full at the end of the migration
101 process, so the migration functions may leave a temporary state behind
104 def decorator(func: Callable[..., None]) -> Callable[..., None]:
105 version = NominatimVersion(major, minor, patch, dbpatch)
106 _MIGRATION_FUNCTIONS.append((version, func))
112 @_migration(3, 5, 0, 99)
113 def import_status_timestamp_change(conn: Connection, **_: Any) -> None:
114 """ Add timezone to timestamp in status table.
116 The import_status table has been changed to include timezone information
119 with conn.cursor() as cur:
120 cur.execute("""ALTER TABLE import_status ALTER COLUMN lastimportdate
121 TYPE timestamp with time zone;""")
124 @_migration(3, 5, 0, 99)
125 def add_nominatim_property_table(conn: Connection, config: Configuration, **_: Any) -> None:
126 """ Add nominatim_property table.
128 if not conn.table_exists('nominatim_properties'):
129 with conn.cursor() as cur:
130 cur.execute(pysql.SQL("""CREATE TABLE nominatim_properties (
133 GRANT SELECT ON TABLE nominatim_properties TO {};
134 """).format(pysql.Identifier(config.DATABASE_WEBUSER)))
136 @_migration(3, 6, 0, 0)
137 def change_housenumber_transliteration(conn: Connection, **_: Any) -> None:
138 """ Transliterate housenumbers.
140 The database schema switched from saving raw housenumbers in
141 placex.housenumber to saving transliterated ones.
143 Note: the function create_housenumber_id() has been dropped in later
146 with conn.cursor() as cur:
147 cur.execute("""CREATE OR REPLACE FUNCTION create_housenumber_id(housenumber TEXT)
152 SELECT array_to_string(array_agg(trans), ';')
154 FROM (SELECT lookup_word as trans,
155 getorcreate_housenumber_id(lookup_word)
156 FROM (SELECT make_standard_name(h) as lookup_word
157 FROM regexp_split_to_table(housenumber, '[,;]') h) x) y;
160 $$ LANGUAGE plpgsql STABLE STRICT;""")
161 cur.execute("DELETE FROM word WHERE class = 'place' and type = 'house'")
162 cur.execute("""UPDATE placex
163 SET housenumber = create_housenumber_id(housenumber)
164 WHERE housenumber is not null""")
167 @_migration(3, 7, 0, 0)
168 def switch_placenode_geometry_index(conn: Connection, **_: Any) -> None:
169 """ Replace idx_placex_geometry_reverse_placeNode index.
171 Make the index slightly more permissive, so that it can also be used
172 when matching up boundaries and place nodes. It makes the index
173 idx_placex_adminname index unnecessary.
175 with conn.cursor() as cur:
176 cur.execute(""" CREATE INDEX IF NOT EXISTS idx_placex_geometry_placenode ON placex
177 USING GIST (geometry)
178 WHERE osm_type = 'N' and rank_search < 26
179 and class = 'place' and type != 'postcode'
180 and linked_place_id is null""")
181 cur.execute(""" DROP INDEX IF EXISTS idx_placex_adminname """)
184 @_migration(3, 7, 0, 1)
185 def install_legacy_tokenizer(conn: Connection, config: Configuration, **_: Any) -> None:
186 """ Setup legacy tokenizer.
188 If no other tokenizer has been configured yet, then create the
189 configuration for the backwards-compatible legacy tokenizer
191 if properties.get_property(conn, 'tokenizer') is None:
192 with conn.cursor() as cur:
193 for table in ('placex', 'location_property_osmline'):
194 has_column = cur.scalar("""SELECT count(*) FROM information_schema.columns
195 WHERE table_name = %s
196 and column_name = 'token_info'""",
199 cur.execute(pysql.SQL('ALTER TABLE {} ADD COLUMN token_info JSONB')
200 .format(pysql.Identifier(table)))
201 tokenizer = tokenizer_factory.create_tokenizer(config, init_db=False,
202 module_name='legacy')
204 tokenizer.migrate_database(config) # type: ignore[attr-defined]
207 @_migration(4, 0, 99, 0)
208 def create_tiger_housenumber_index(conn: Connection, **_: Any) -> None:
209 """ Create idx_location_property_tiger_parent_place_id with included
212 The inclusion is needed for efficient lookup of housenumbers in
213 full address searches.
215 if conn.server_version_tuple() >= (11, 0, 0):
216 with conn.cursor() as cur:
217 cur.execute(""" CREATE INDEX IF NOT EXISTS
218 idx_location_property_tiger_housenumber_migrated
219 ON location_property_tiger
220 USING btree(parent_place_id)
221 INCLUDE (startnumber, endnumber) """)
224 @_migration(4, 0, 99, 1)
225 def create_interpolation_index_on_place(conn: Connection, **_: Any) -> None:
226 """ Create idx_place_interpolations for lookup of interpolation lines
229 with conn.cursor() as cur:
230 cur.execute("""CREATE INDEX IF NOT EXISTS idx_place_interpolations
231 ON place USING gist(geometry)
232 WHERE osm_type = 'W' and address ? 'interpolation'""")
235 @_migration(4, 0, 99, 2)
236 def add_step_column_for_interpolation(conn: Connection, **_: Any) -> None:
237 """ Add a new column 'step' to the interpolations table.
239 Also converts the data into the stricter format which requires that
240 startnumbers comply with the odd/even requirements.
242 if conn.table_has_column('location_property_osmline', 'step'):
245 with conn.cursor() as cur:
246 # Mark invalid all interpolations with no intermediate numbers.
247 cur.execute("""UPDATE location_property_osmline SET startnumber = null
248 WHERE endnumber - startnumber <= 1 """)
249 # Align the start numbers where odd/even does not match.
250 cur.execute("""UPDATE location_property_osmline
251 SET startnumber = startnumber + 1,
252 linegeo = ST_LineSubString(linegeo,
253 1.0 / (endnumber - startnumber)::float,
255 WHERE (interpolationtype = 'odd' and startnumber % 2 = 0)
256 or (interpolationtype = 'even' and startnumber % 2 = 1)
258 # Mark invalid odd/even interpolations with no intermediate numbers.
259 cur.execute("""UPDATE location_property_osmline SET startnumber = null
260 WHERE interpolationtype in ('odd', 'even')
261 and endnumber - startnumber = 2""")
262 # Finally add the new column and populate it.
263 cur.execute("ALTER TABLE location_property_osmline ADD COLUMN step SMALLINT")
264 cur.execute("""UPDATE location_property_osmline
265 SET step = CASE WHEN interpolationtype = 'all'
270 @_migration(4, 0, 99, 3)
271 def add_step_column_for_tiger(conn: Connection, **_: Any) -> None:
272 """ Add a new column 'step' to the tiger data table.
274 if conn.table_has_column('location_property_tiger', 'step'):
277 with conn.cursor() as cur:
278 cur.execute("ALTER TABLE location_property_tiger ADD COLUMN step SMALLINT")
279 cur.execute("""UPDATE location_property_tiger
280 SET step = CASE WHEN interpolationtype = 'all'
285 @_migration(4, 0, 99, 4)
286 def add_derived_name_column_for_country_names(conn: Connection, **_: Any) -> None:
287 """ Add a new column 'derived_name' which in the future takes the
288 country names as imported from OSM data.
290 if not conn.table_has_column('country_name', 'derived_name'):
291 with conn.cursor() as cur:
292 cur.execute("ALTER TABLE country_name ADD COLUMN derived_name public.HSTORE")
295 @_migration(4, 0, 99, 5)
296 def mark_internal_country_names(conn: Connection, config: Configuration, **_: Any) -> None:
297 """ Names from the country table should be marked as internal to prevent
298 them from being deleted. Only necessary for ICU tokenizer.
300 import psycopg2.extras # pylint: disable=import-outside-toplevel
302 tokenizer = tokenizer_factory.get_tokenizer_for_db(config)
303 with tokenizer.name_analyzer() as analyzer:
304 with conn.cursor() as cur:
305 psycopg2.extras.register_hstore(cur)
306 cur.execute("SELECT country_code, name FROM country_name")
308 for country_code, names in cur:
311 names['countrycode'] = country_code
312 analyzer.add_country_names(country_code, names)
315 @_migration(4, 1, 99, 0)
316 def add_place_deletion_todo_table(conn: Connection, **_: Any) -> None:
317 """ Add helper table for deleting data on updates.
319 The table is only necessary when updates are possible, i.e.
320 the database is not in freeze mode.
322 if conn.table_exists('place'):
323 with conn.cursor() as cur:
324 cur.execute("""CREATE TABLE IF NOT EXISTS place_to_be_deleted (
329 deferred BOOLEAN)""")
332 @_migration(4, 1, 99, 1)
333 def split_pending_index(conn: Connection, **_: Any) -> None:
334 """ Reorganise indexes for pending updates.
336 if conn.table_exists('place'):
337 with conn.cursor() as cur:
338 cur.execute("""CREATE INDEX IF NOT EXISTS idx_placex_rank_address_sector
339 ON placex USING BTREE (rank_address, geometry_sector)
340 WHERE indexed_status > 0""")
341 cur.execute("""CREATE INDEX IF NOT EXISTS idx_placex_rank_boundaries_sector
342 ON placex USING BTREE (rank_search, geometry_sector)
343 WHERE class = 'boundary' and type = 'administrative'
344 and indexed_status > 0""")
345 cur.execute("DROP INDEX IF EXISTS idx_placex_pendingsector")
348 @_migration(4, 2, 99, 0)
349 def enable_forward_dependencies(conn: Connection, **_: Any) -> None:
350 """ Create indexes for updates with forward dependency tracking (long-running).
352 if conn.table_exists('planet_osm_ways'):
353 with conn.cursor() as cur:
354 cur.execute("""SELECT * FROM pg_indexes
355 WHERE tablename = 'planet_osm_ways'
356 and indexdef LIKE '%nodes%'""")
357 if cur.rowcount == 0:
358 cur.execute("""CREATE OR REPLACE FUNCTION public.planet_osm_index_bucket(bigint[])
360 LANGUAGE sql IMMUTABLE
362 SELECT ARRAY(SELECT DISTINCT unnest($1) >> 5)
364 cur.execute("""CREATE INDEX planet_osm_ways_nodes_bucket_idx
366 USING gin (planet_osm_index_bucket(nodes))
367 WITH (fastupdate=off)""")
368 cur.execute("""CREATE INDEX planet_osm_rels_parts_idx
369 ON planet_osm_rels USING gin (parts)
370 WITH (fastupdate=off)""")
371 cur.execute("ANALYZE planet_osm_ways")
374 @_migration(4, 2, 99, 1)
375 def add_improved_geometry_reverse_placenode_index(conn: Connection, **_: Any) -> None:
376 """ Create improved index for reverse lookup of place nodes.
378 with conn.cursor() as cur:
379 cur.execute("""CREATE INDEX IF NOT EXISTS idx_placex_geometry_reverse_lookupPlaceNode
381 USING gist (ST_Buffer(geometry, reverse_place_diameter(rank_search)))
382 WHERE rank_address between 4 and 25 AND type != 'postcode'
383 AND name is not null AND linked_place_id is null AND osm_type = 'N'
386 @_migration(4, 4, 99, 0)
387 def create_postcode_area_lookup_index(conn: Connection, **_: Any) -> None:
388 """ Create index needed for looking up postcode areas from postocde points.
390 with conn.cursor() as cur:
391 cur.execute("""CREATE INDEX IF NOT EXISTS idx_placex_postcode_areas
392 ON placex USING BTREE (country_code, postcode)
393 WHERE osm_type = 'R' AND class = 'boundary' AND type = 'postal_code'
397 @_migration(4, 4, 99, 1)
398 def create_postcode_parent_index(conn: Connection, **_: Any) -> None:
399 """ Create index needed for updating postcodes when a parent changes.
401 if conn.table_exists('planet_osm_ways'):
402 with conn.cursor() as cur:
403 cur.execute("""CREATE INDEX IF NOT EXISTS
404 idx_location_postcode_parent_place_id
405 ON location_postcode USING BTREE (parent_place_id)""")