3 This page describes database migrations necessary to update existing databases
4 to newer versions of Nominatim.
6 SQL statements should be executed from the PostgreSQL commandline. Execute
7 `psql nominatim` to enter command line mode.
11 ### Change of layout of search_name_* tables
13 The table need a different index for nearest place lookup. Recreate the
14 indexes using the following shell script:
17 for table in `psql -d nominatim -c "SELECT tablename FROM pg_tables WHERE tablename LIKE 'search_name_%'" -tA | grep -v search_name_blank`;
19 psql -d nominatim -c "DROP INDEX idx_${table}_centroid_place; CREATE INDEX idx_${table}_centroid_place ON ${table} USING gist (centroid) WHERE ((address_rank >= 2) AND (address_rank <= 25)); DROP INDEX idx_${table}_centroid_street; CREATE INDEX idx_${table}_centroid_street ON ${table} USING gist (centroid) WHERE ((address_rank >= 26) AND (address_rank <= 27))";
23 ### Removal of html output
25 The debugging UI is no longer directly provided with Nominatim. Instead we
26 now provide a simple Javascript application. Please refer to
27 [Setting up the Nominatim UI](../Setup-Nominatim-UI) for details on how to
30 The icons served together with the API responses have been moved to the
31 nominatim-ui project as well. If you want to keep the `icon` field in the
32 response, you need to set `CONST_MapIcon_URL` to the URL of the `/mapicon`
33 directory of nominatim-ui.
35 ### Change order during indexing
37 When reindexing places during updates, there is now a different order used
38 which needs a different database index. Create it with the following SQL command:
41 CREATE INDEX idx_placex_pendingsector_rank_address
43 USING BTREE (rank_address, geometry_sector)
44 WHERE indexed_status > 0;
47 You can then drop the old index with:
50 DROP INDEX idx_placex_pendingsector;
55 This index has been unused ever since the query using it was changed two years ago. Saves about 12GB on a planet installation.
58 DROP INDEX idx_placex_geometry_reverse_lookupPoint;
61 ### Switching to dotenv
63 As part of the work changing the configuration format, the configuration for
64 the website is now using a separate configuration file. To create the
65 configuration file, run the following command after updating:
68 ./utils/setup.php --setup-website
73 ### New Wikipedia/Wikidata importance tables
75 The `wikipedia_*` tables have a new format that also includes references to
76 Wikidata. You need to update the computation functions and the tables as
79 * download the new Wikipedia tables as described in the import section
80 * reimport the tables: `./utils/setup.php --import-wikipedia-articles`
81 * update the functions: `./utils/setup.php --create-functions --enable-diff-updates`
82 * create a new lookup index:
84 CREATE INDEX idx_placex_wikidata
86 USING BTREE ((extratags -> 'wikidata'))
87 WHERE extratags ? 'wikidata'
92 * compute importance: `./utils/update.php --recompute-importance`
94 The last step takes about 10 hours on the full planet.
96 Remove one function (it will be recreated in the next step):
99 DROP FUNCTION create_country(hstore,character varying);
102 Finally, update all SQL functions:
105 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
110 ### Reorganisation of location_area_country table
112 The table `location_area_country` has been optimized. You need to switch to the
113 new format when you run updates. While updates are disabled, run the following
117 CREATE TABLE location_area_country_new AS
118 SELECT place_id, country_code, geometry FROM location_area_country;
119 DROP TABLE location_area_country;
120 ALTER TABLE location_area_country_new RENAME TO location_area_country;
121 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry);
122 CREATE INDEX idx_location_area_country_place_id ON location_area_country USING BTREE (place_id);
125 Finally, update all SQL functions:
128 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
133 ### New database connection string (DSN) format
135 Previously database connection setting (`CONST_Database_DSN` in `settings/*.php`) had the format
137 * (simple) `pgsql://@/nominatim`
138 * (complex) `pgsql://johndoe:secret@machine1.domain.com:1234/db1`
142 * (simple) `pgsql:dbname=nominatim`
143 * (complex) `pgsql:dbname=db1;host=machine1.domain.com;port=1234;user=johndoe;password=secret`
145 ### Natural Earth country boundaries no longer needed as fallback
148 DROP TABLE country_naturalearthdata;
151 Finally, update all SQL functions:
154 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
157 ### Configurable Address Levels
159 The new configurable address levels require a new table. Create it with the
163 ./utils/update.php --update-address-levels
168 ### New reverse algorithm
170 The reverse algorithm has changed and requires new indexes. Run the following
171 SQL statements to create the indexes:
174 CREATE INDEX idx_placex_geometry_reverse_lookupPoint
176 USING gist (geometry)
177 WHERE (name IS NOT null or housenumber IS NOT null or rank_address BETWEEN 26 AND 27)
178 AND class NOT IN ('railway','tunnel','bridge','man_made')
179 AND rank_address >= 26
180 AND indexed_status = 0
181 AND linked_place_id IS null;
182 CREATE INDEX idx_placex_geometry_reverse_lookupPolygon
183 ON placex USING gist (geometry)
184 WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon')
185 AND rank_address between 4 and 25
186 AND type != 'postcode'
188 AND indexed_status = 0
189 AND linked_place_id is null;
190 CREATE INDEX idx_placex_geometry_reverse_placeNode
191 ON placex USING gist (geometry)
193 AND rank_search between 5 and 25
195 AND type != 'postcode'
197 AND indexed_status = 0
198 AND linked_place_id is null;
201 You also need to grant the website user access to the `country_osm_grid` table:
204 GRANT SELECT ON table country_osm_grid to "www-user";
207 Replace the `www-user` with the user name of your website server if necessary.
209 You can now drop the unused indexes:
212 DROP INDEX idx_placex_reverse_geometry;
215 Finally, update all SQL functions:
218 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
225 A new separate table for artificially computed postcode centroids was introduced.
226 Migration to the new format is possible but **not recommended**.
228 Create postcode table and indexes, running the following SQL statements:
231 CREATE TABLE location_postcode
232 (place_id BIGINT, parent_place_id BIGINT, rank_search SMALLINT,
233 rank_address SMALLINT, indexed_status SMALLINT, indexed_date TIMESTAMP,
234 country_code varchar(2), postcode TEXT,
235 geometry GEOMETRY(Geometry, 4326));
236 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry);
237 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id);
238 CREATE INDEX idx_postcode_postcode ON location_postcode USING BTREE (postcode);
239 GRANT SELECT ON location_postcode TO "www-data";
240 DROP TYPE IF EXISTS nearfeaturecentr CASCADE;
241 CREATE TYPE nearfeaturecentr AS (
244 rank_address smallint,
245 rank_search smallint,
253 Add postcode column to `location_area` tables with SQL statement:
256 ALTER TABLE location_area ADD COLUMN postcode TEXT;
259 Then reimport the functions:
262 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
265 Create appropriate triggers with SQL:
268 CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
269 FOR EACH ROW EXECUTE PROCEDURE postcode_update();
272 Finally populate the postcode table (will take a while):
275 ./utils/setup.php --calculate-postcodes --index --index-noanalyse
278 This will create a working database. You may also delete the old artificial
279 postcodes now. Note that this may be expensive and is not absolutely necessary.
280 The following SQL statement will remove them:
283 DELETE FROM place_addressline a USING placex p
284 WHERE a.address_place_id = p.place_id and p.osm_type = 'P';
285 ALTER TABLE placex DISABLE TRIGGER USER;
286 DELETE FROM placex WHERE osm_type = 'P';
287 ALTER TABLE placex ENABLE TRIGGER USER;