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.
12 from nominatim.db import properties
13 from nominatim.db.connection import connect
14 from nominatim.version import NOMINATIM_VERSION, version_str
15 from nominatim.tools import refresh
16 from nominatim.tokenizer import factory as tokenizer_factory
17 from nominatim.errors import UsageError
19 LOG = logging.getLogger()
21 _MIGRATION_FUNCTIONS = []
23 def migrate(config, paths):
24 """ Check for the current database version and execute migrations,
27 with connect(config.get_libpq_dsn()) as conn:
28 if conn.table_exists('nominatim_properties'):
29 db_version_str = properties.get_property(conn, 'database_version')
33 if db_version_str is not None:
34 parts = db_version_str.split('.')
35 db_version = tuple(int(x) for x in parts[:2] + parts[2].split('-'))
37 if db_version == NOMINATIM_VERSION:
38 LOG.warning("Database already at latest version (%s)", db_version_str)
41 LOG.info("Detected database version: %s", db_version_str)
43 db_version = _guess_version(conn)
46 has_run_migration = False
47 for version, func in _MIGRATION_FUNCTIONS:
48 if db_version <= version:
49 LOG.warning("Runnning: %s (%s)", func.__doc__.split('\n', 1)[0],
50 '{}.{}.{}-{}'.format(*version))
51 kwargs = dict(conn=conn, config=config, paths=paths)
54 has_run_migration = True
57 LOG.warning('Updating SQL functions.')
58 refresh.create_functions(conn, config)
59 tokenizer = tokenizer_factory.get_tokenizer_for_db(config)
60 tokenizer.update_sql_functions(config)
62 properties.set_property(conn, 'database_version', version_str())
69 def _guess_version(conn):
70 """ Guess a database version when there is no property table yet.
71 Only migrations for 3.6 and later are supported, so bail out
72 when the version seems older.
74 with conn.cursor() as cur:
75 # In version 3.6, the country_name table was updated. Check for that.
76 cnt = cur.scalar("""SELECT count(*) FROM
77 (SELECT svals(name) FROM country_name
78 WHERE country_code = 'gb')x;
81 LOG.fatal('It looks like your database was imported with a version '
82 'prior to 3.6.0. Automatic migration not possible.')
83 raise UsageError('Migration not possible.')
89 def _migration(major, minor, patch=0, dbpatch=0):
90 """ Decorator for a single migration step. The parameters describe the
91 version after which the migration is applicable, i.e before changing
92 from the given version to the next, the migration is required.
94 All migrations are run in the order in which they are defined in this
95 file. Do not run global SQL scripts for migrations as you cannot be sure
96 that these scripts do the same in later versions.
98 Functions will always be reimported in full at the end of the migration
99 process, so the migration functions may leave a temporary state behind
103 _MIGRATION_FUNCTIONS.append(((major, minor, patch, dbpatch), func))
109 @_migration(3, 5, 0, 99)
110 def import_status_timestamp_change(conn, **_):
111 """ Add timezone to timestamp in status table.
113 The import_status table has been changed to include timezone information
116 with conn.cursor() as cur:
117 cur.execute("""ALTER TABLE import_status ALTER COLUMN lastimportdate
118 TYPE timestamp with time zone;""")
121 @_migration(3, 5, 0, 99)
122 def add_nominatim_property_table(conn, config, **_):
123 """ Add nominatim_property table.
125 if not conn.table_exists('nominatim_properties'):
126 with conn.cursor() as cur:
127 cur.execute("""CREATE TABLE nominatim_properties (
130 GRANT SELECT ON TABLE nominatim_properties TO "{}";
131 """.format(config.DATABASE_WEBUSER))
133 @_migration(3, 6, 0, 0)
134 def change_housenumber_transliteration(conn, **_):
135 """ Transliterate housenumbers.
137 The database schema switched from saving raw housenumbers in
138 placex.housenumber to saving transliterated ones.
140 Note: the function create_housenumber_id() has been dropped in later
143 with conn.cursor() as cur:
144 cur.execute("""CREATE OR REPLACE FUNCTION create_housenumber_id(housenumber TEXT)
149 SELECT array_to_string(array_agg(trans), ';')
151 FROM (SELECT lookup_word as trans,
152 getorcreate_housenumber_id(lookup_word)
153 FROM (SELECT make_standard_name(h) as lookup_word
154 FROM regexp_split_to_table(housenumber, '[,;]') h) x) y;
157 $$ LANGUAGE plpgsql STABLE STRICT;""")
158 cur.execute("DELETE FROM word WHERE class = 'place' and type = 'house'")
159 cur.execute("""UPDATE placex
160 SET housenumber = create_housenumber_id(housenumber)
161 WHERE housenumber is not null""")
164 @_migration(3, 7, 0, 0)
165 def switch_placenode_geometry_index(conn, **_):
166 """ Replace idx_placex_geometry_reverse_placeNode index.
168 Make the index slightly more permissive, so that it can also be used
169 when matching up boundaries and place nodes. It makes the index
170 idx_placex_adminname index unnecessary.
172 with conn.cursor() as cur:
173 cur.execute(""" CREATE INDEX IF NOT EXISTS idx_placex_geometry_placenode ON placex
174 USING GIST (geometry)
175 WHERE osm_type = 'N' and rank_search < 26
176 and class = 'place' and type != 'postcode'
177 and linked_place_id is null""")
178 cur.execute(""" DROP INDEX IF EXISTS idx_placex_adminname """)
181 @_migration(3, 7, 0, 1)
182 def install_legacy_tokenizer(conn, config, **_):
183 """ Setup legacy tokenizer.
185 If no other tokenizer has been configured yet, then create the
186 configuration for the backwards-compatible legacy tokenizer
188 if properties.get_property(conn, 'tokenizer') is None:
189 with conn.cursor() as cur:
190 for table in ('placex', 'location_property_osmline'):
191 has_column = cur.scalar("""SELECT count(*) FROM information_schema.columns
192 WHERE table_name = %s
193 and column_name = 'token_info'""",
196 cur.execute('ALTER TABLE {} ADD COLUMN token_info JSONB'.format(table))
197 tokenizer = tokenizer_factory.create_tokenizer(config, init_db=False,
198 module_name='legacy')
200 tokenizer.migrate_database(config)
203 @_migration(4, 0, 99, 0)
204 def create_tiger_housenumber_index(conn, **_):
205 """ Create idx_location_property_tiger_parent_place_id with included
208 The inclusion is needed for efficient lookup of housenumbers in
209 full address searches.
211 if conn.server_version_tuple() >= (11, 0, 0):
212 with conn.cursor() as cur:
213 cur.execute(""" CREATE INDEX IF NOT EXISTS
214 idx_location_property_tiger_housenumber_migrated
215 ON location_property_tiger
216 USING btree(parent_place_id)
217 INCLUDE (startnumber, endnumber) """)
220 @_migration(4, 0, 99, 1)
221 def create_interpolation_index_on_place(conn, **_):
222 """ Create idx_place_interpolations for lookup of interpolation lines
225 with conn.cursor() as cur:
226 cur.execute("""CREATE INDEX IF NOT EXISTS idx_place_interpolations
227 ON place USING gist(geometry)
228 WHERE osm_type = 'W' and address ? 'interpolation'""")
231 @_migration(4, 0, 99, 2)
232 def add_step_column_for_interpolation(conn, **_):
233 """ Add a new column 'step' to the interpolations table.
235 Also convers the data into the stricter format which requires that
236 startnumbers comply with the odd/even requirements.
238 if conn.table_has_column('location_property_osmline', 'step'):
241 with conn.cursor() as cur:
242 # Mark invalid all interpolations with no intermediate numbers.
243 cur.execute("""UPDATE location_property_osmline SET startnumber = null
244 WHERE endnumber - startnumber <= 1 """)
245 # Align the start numbers where odd/even does not match.
246 cur.execute("""UPDATE location_property_osmline
247 SET startnumber = startnumber + 1,
248 linegeo = ST_LineSubString(linegeo,
249 1.0 / (endnumber - startnumber)::float,
251 WHERE (interpolationtype = 'odd' and startnumber % 2 = 0)
252 or (interpolationtype = 'even' and startnumber % 2 = 1)
254 # Mark invalid odd/even interpolations with no intermediate numbers.
255 cur.execute("""UPDATE location_property_osmline SET startnumber = null
256 WHERE interpolationtype in ('odd', 'even')
257 and endnumber - startnumber = 2""")
258 # Finally add the new column and populate it.
259 cur.execute("ALTER TABLE location_property_osmline ADD COLUMN step SMALLINT")
260 cur.execute("""UPDATE location_property_osmline
261 SET step = CASE WHEN interpolationtype = 'all'
266 @_migration(4, 0, 99, 3)
267 def add_step_column_for_tiger(conn, **_):
268 """ Add a new column 'step' to the tiger data table.
270 if conn.table_has_column('location_property_tiger', 'step'):
273 with conn.cursor() as cur:
274 cur.execute("ALTER TABLE location_property_tiger ADD COLUMN step SMALLINT")
275 cur.execute("""UPDATE location_property_tiger
276 SET step = CASE WHEN interpolationtype = 'all'
281 @_migration(4, 0, 99, 4)
282 def add_derived_name_column_for_country_names(conn, **_):
283 """ Add a new column 'derived_name' which in the future takes the
284 country names as imported from OSM data.
286 if not conn.table_has_column('country_name', 'derived_name'):
287 with conn.cursor() as cur:
288 cur.execute("ALTER TABLE country_name ADD COLUMN derived_name public.HSTORE")
291 @_migration(4, 0, 99, 5)
292 def mark_internal_country_names(conn, config, **_):
293 """ Names from the country table should be marked as internal to prevent
294 them from being deleted. Only necessary for ICU tokenizer.
296 import psycopg2.extras # pylint: disable=import-outside-toplevel
298 tokenizer = tokenizer_factory.get_tokenizer_for_db(config)
299 with tokenizer.name_analyzer() as analyzer:
300 with conn.cursor() as cur:
301 psycopg2.extras.register_hstore(cur)
302 cur.execute("SELECT country_code, name FROM country_name")
304 for country_code, names in cur:
307 names['countrycode'] = country_code
308 analyzer.add_country_names(country_code, names)