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 postgres commandline. Execute
7 `psql nominatim` to enter command line mode.
12 ### New database connection string (DSN) format
14 Previously database connection setting (`CONST_Database_DSN` in `settings/*.php`) had the format
16 * (simple) `pgsql://@/nominatim`
17 * (complex) `pgsql://johndoe:secret@machine1.domain.com:1234/db1`
21 * (simple) `pgsql:dbname=nominatim`
22 * (complex) `pgsql:dbname=db1;host=machine1.domain.com;port=1234;user=johndoe;password=secret`
24 ### Natural Earth country boundaries no longer needed as fallback
27 DROP TABLE country_naturalearthdata;
30 Finally, update all SQL functions:
33 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
36 ### Configurable Address Levels
38 The new configurable address levels require a new table. Create it with the
42 ./utils/update.php --update-address-levels
47 ### New reverse algorithm
49 The reverse algorithm has changed and requires new indexes. Run the following
50 SQL statements to create the indexes:
53 CREATE INDEX idx_placex_geometry_reverse_lookupPoint
54 ON placex USING gist (geometry)
55 WHERE (name is not null or housenumber is not null or rank_address between 26 and 27)
56 AND class not in ('railway','tunnel','bridge','man_made')
57 AND rank_address >= 26 AND indexed_status = 0 AND linked_place_id is null;
58 CREATE INDEX idx_placex_geometry_reverse_lookupPolygon
59 ON placex USING gist (geometry)
60 WHERE St_GeometryType(geometry) in ('ST_Polygon', 'ST_MultiPolygon')
61 AND rank_address between 4 and 25 AND type != 'postcode'
62 AND name is not null AND indexed_status = 0 AND linked_place_id is null;
63 CREATE INDEX idx_placex_geometry_reverse_placeNode
64 ON placex USING gist (geometry)
65 WHERE osm_type = 'N' AND rank_search between 5 and 25
66 AND class = 'place' AND type != 'postcode'
67 AND name is not null AND indexed_status = 0 AND linked_place_id is null;
70 You also need to grant the website user access to the `country_osm_grid` table:
73 GRANT SELECT ON table country_osm_grid to "www-user";
76 Replace the `www-user` with the user name of your website server if necessary.
78 You can now drop the unused indexes:
81 DROP INDEX idx_placex_reverse_geometry;
84 Finally, update all SQL functions:
87 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
94 A new separate table for artificially computed postcode centroids was introduced.
95 Migration to the new format is possible but **not recommended**.
97 Create postcode table and indexes, running the following SQL statements:
100 CREATE TABLE location_postcode
101 (place_id BIGINT, parent_place_id BIGINT, rank_search SMALLINT,
102 rank_address SMALLINT, indexed_status SMALLINT, indexed_date TIMESTAMP,
103 country_code varchar(2), postcode TEXT,
104 geometry GEOMETRY(Geometry, 4326));
105 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry);
106 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id);
107 CREATE INDEX idx_postcode_postcode ON location_postcode USING BTREE (postcode);
108 GRANT SELECT ON location_postcode TO "www-data";
109 drop type if exists nearfeaturecentr cascade;
110 create type nearfeaturecentr as (
113 rank_address smallint,
114 rank_search smallint,
122 Add postcode column to `location_area` tables with SQL statement:
125 ALTER TABLE location_area ADD COLUMN postcode TEXT;
128 Then reimport the functions:
131 ./utils/setup.php --create-functions --enable-diff-updates --create-partition-functions
134 Create appropriate triggers with SQL:
137 CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
138 FOR EACH ROW EXECUTE PROCEDURE postcode_update();
141 Finally populate the postcode table (will take a while):
144 ./utils/setup.php --calculate-postcodes --index --index-noanalyse
147 This will create a working database. You may also delete the old artificial
148 postcodes now. Note that this may be expensive and is not absolutely necessary.
149 The following SQL statement will remove them:
152 DELETE FROM place_addressline a USING placex p
153 WHERE a.address_place_id = p.place_id and p.osm_type = 'P';
154 ALTER TABLE placex DISABLE TRIGGER USER;
155 DELETE FROM placex WHERE osm_type = 'P';
156 ALTER TABLE placex ENABLE TRIGGER USER;