1 -- SPDX-License-Identifier: GPL-2.0-only
3 -- This file is part of Nominatim. (https://nominatim.org)
5 -- Copyright (C) 2026 by the Nominatim developer community.
6 -- For a full list of authors see the git log.
8 drop table if exists import_status;
9 CREATE TABLE import_status (
10 lastimportdate timestamp with time zone NOT NULL,
15 drop table if exists import_osmosis_log;
16 CREATE TABLE import_osmosis_log (
25 DROP TABLE IF EXISTS nominatim_properties;
26 CREATE TABLE nominatim_properties (
27 property TEXT NOT NULL,
31 drop table IF EXISTS location_area CASCADE;
32 CREATE TABLE location_area (
33 place_id BIGINT NOT NULL,
34 keywords INTEGER[] NOT NULL,
35 partition SMALLINT NOT NULL,
36 rank_search SMALLINT NOT NULL,
37 rank_address SMALLINT NOT NULL,
38 country_code VARCHAR(2),
39 isguess BOOL NOT NULL,
41 centroid GEOMETRY(Point, 4326) NOT NULL,
42 geometry GEOMETRY(Geometry, 4326) NOT NULL
45 CREATE TABLE location_area_large () INHERITS (location_area);
47 DROP TABLE IF EXISTS location_area_country;
48 CREATE TABLE location_area_country (
49 place_id BIGINT NOT NULL,
50 country_code varchar(2) NOT NULL,
51 geometry GEOMETRY(Geometry, 4326) NOT NULL
52 ) {{db.tablespace.address_data}};
53 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
56 CREATE TABLE location_property_tiger (
57 place_id BIGINT NOT NULL,
58 parent_place_id BIGINT,
59 startnumber INTEGER NOT NULL,
60 endnumber INTEGER NOT NULL,
61 step SMALLINT NOT NULL,
62 partition SMALLINT NOT NULL,
63 linegeo GEOMETRY NOT NULL,
66 drop table if exists location_property_osmline;
67 CREATE TABLE location_property_osmline (
68 place_id BIGINT NOT NULL,
69 osm_id BIGINT NOT NULL,
70 parent_place_id BIGINT,
71 geometry_sector INTEGER NOT NULL,
72 indexed_date TIMESTAMP,
76 partition SMALLINT NOT NULL,
77 indexed_status SMALLINT NOT NULL,
78 linegeo GEOMETRY NOT NULL,
80 token_info JSONB, -- custom column for tokenizer use only
82 country_code VARCHAR(2)
83 ){{db.tablespace.search_data}};
84 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
85 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
86 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}}
87 WHERE startnumber is not null;
89 drop table IF EXISTS search_name;
90 {% if not db.reverse_only %}
91 CREATE TABLE search_name (
92 place_id BIGINT NOT NULL,
93 importance FLOAT NOT NULL,
94 search_rank SMALLINT NOT NULL,
95 address_rank SMALLINT NOT NULL,
96 name_vector integer[] NOT NULL,
97 nameaddress_vector integer[] NOT NULL,
98 country_code varchar(2),
99 centroid GEOMETRY(Geometry, 4326) NOT NULL
100 ) {{db.tablespace.search_data}};
101 CREATE UNIQUE INDEX idx_search_name_place_id
102 ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
105 drop table IF EXISTS place_addressline;
106 CREATE TABLE place_addressline (
107 place_id BIGINT NOT NULL,
108 address_place_id BIGINT NOT NULL,
109 distance FLOAT NOT NULL,
110 cached_rank_address SMALLINT NOT NULL,
111 fromarea boolean NOT NULL,
112 isaddress boolean NOT NULL
113 ) {{db.tablespace.search_data}};
114 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
116 --------- PLACEX - storage for all indexed places -----------------
118 DROP TABLE IF EXISTS placex;
119 CREATE TABLE placex (
120 place_id BIGINT NOT NULL,
121 parent_place_id BIGINT,
122 linked_place_id BIGINT,
124 indexed_date TIMESTAMP,
125 geometry_sector INTEGER NOT NULL,
126 rank_address SMALLINT NOT NULL,
127 rank_search SMALLINT NOT NULL,
128 partition SMALLINT NOT NULL,
129 indexed_status SMALLINT NOT NULL,
130 LIKE place INCLUDING CONSTRAINTS,
131 wikipedia TEXT, -- calculated wikipedia article name (language:title)
132 token_info JSONB, -- custom column for tokenizer use only
133 country_code varchar(2),
136 centroid GEOMETRY(Geometry, 4326) NOT NULL
137 ) {{db.tablespace.search_data}};
139 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
140 {% for osm_type in ('N', 'W', 'R') %}
141 CREATE INDEX idx_placex_osmid_{{osm_type | lower}} ON placex
142 USING BTREE (osm_id) {{db.tablespace.search_index}}
143 WHERE osm_type = '{{osm_type}}';
146 -- Usage: - removing linkage status on update
147 -- - lookup linked places for /details
148 CREATE INDEX idx_placex_linked_place_id ON placex
149 USING BTREE (linked_place_id) {{db.tablespace.address_index}}
150 WHERE linked_place_id IS NOT NULL;
152 -- Usage: - check that admin boundaries do not overtake each other rank-wise
153 -- - check that place node in a admin boundary with the same address level
154 -- - boundary is not completely contained in a place area
155 -- - parenting of large-area or unparentable features
156 CREATE INDEX idx_placex_geometry_address_area_candidates ON placex
157 USING gist (geometry) {{db.tablespace.address_index}}
158 WHERE rank_address between 1 and 25
159 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
161 -- Usage: - POI is within building with housenumber
162 CREATE INDEX idx_placex_geometry_buildings ON placex
163 USING SPGIST (geometry) {{db.tablespace.address_index}}
164 WHERE address is not null and rank_search = 30
165 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
167 -- Usage: - linking of similar named places to boundaries
168 -- - linking of place nodes with same type to boundaries
169 CREATE INDEX idx_placex_geometry_placenode ON placex
170 USING SPGIST (geometry) {{db.tablespace.address_index}}
171 WHERE osm_type = 'N' and rank_search < 26 and class = 'place';
173 -- Usage: - is node part of a way?
174 -- - find parent of interpolation spatially
175 CREATE INDEX idx_placex_geometry_lower_rank_ways ON placex
176 USING SPGIST (geometry) {{db.tablespace.address_index}}
177 WHERE osm_type = 'W' and rank_search >= 26;
179 -- Usage: - linking place nodes by wikidata tag to boundaries
180 CREATE INDEX idx_placex_wikidata on placex
181 USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}}
182 WHERE extratags ? 'wikidata' and class = 'place'
183 and osm_type = 'N' and rank_search < 26;
185 -- The following two indexes function as a todo list for indexing.
187 CREATE INDEX idx_placex_rank_address_sector ON placex
188 USING BTREE (rank_address, geometry_sector) {{db.tablespace.address_index}}
189 WHERE indexed_status > 0;
191 CREATE INDEX idx_placex_rank_boundaries_sector ON placex
192 USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}}
193 WHERE class = 'boundary' and type = 'administrative'
194 and indexed_status > 0;
197 DROP SEQUENCE IF EXISTS seq_place;
198 CREATE SEQUENCE seq_place start 1;
200 -- Table for synthetic postcodes.
201 DROP TABLE IF EXISTS location_postcodes;
202 CREATE TABLE location_postcodes (
203 place_id BIGINT NOT NULL,
204 parent_place_id BIGINT,
206 rank_search SMALLINT NOT NULL,
207 indexed_status SMALLINT NOT NULL,
208 indexed_date TIMESTAMP,
209 country_code varchar(2) NOT NULL,
210 postcode TEXT NOT NULL,
211 centroid GEOMETRY(Geometry, 4326) NOT NULL,
212 geometry GEOMETRY(Geometry, 4326) NOT NULL
214 CREATE UNIQUE INDEX idx_location_postcodes_id ON location_postcodes
215 USING BTREE (place_id) {{db.tablespace.search_index}};
216 CREATE INDEX idx_location_postcodes_geometry ON location_postcodes
217 USING GIST (geometry) {{db.tablespace.search_index}};
218 CREATE INDEX IF NOT EXISTS idx_location_postcodes_postcode
219 ON location_postcodes USING BTREE (postcode, country_code)
220 {{db.tablespace.search_index}};
221 CREATE INDEX IF NOT EXISTS idx_location_postcodes_osmid
222 ON location_postcodes USING BTREE (osm_id) {{db.tablespace.search_index}};
224 -- Table to store location of entrance nodes
225 DROP TABLE IF EXISTS placex_entrance;
226 CREATE TABLE placex_entrance (
227 place_id BIGINT NOT NULL,
228 osm_id BIGINT NOT NULL,
230 location GEOMETRY(Point, 4326) NOT NULL,
233 CREATE UNIQUE INDEX idx_placex_entrance_place_id_osm_id ON placex_entrance
234 USING BTREE (place_id, osm_id) {{db.tablespace.search_index}};
236 -- Create an index on the place table for lookups to populate the entrance
238 CREATE INDEX IF NOT EXISTS idx_placex_entrance_lookup ON place
240 WHERE class IN ('routing:entrance', 'entrance');
242 DROP TABLE IF EXISTS import_polygon_error;
243 CREATE TABLE import_polygon_error (
249 country_code varchar(2),
252 prevgeometry GEOMETRY(Geometry, 4326),
253 newgeometry GEOMETRY(Geometry, 4326)
255 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
257 DROP TABLE IF EXISTS import_polygon_delete;
258 CREATE TABLE import_polygon_delete (
264 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
266 DROP SEQUENCE IF EXISTS file;
267 CREATE SEQUENCE file start 1;
269 {% if 'wikimedia_importance' not in db.tables and 'wikipedia_article' not in db.tables %}
270 -- create dummy tables here, if nothing was imported
271 CREATE TABLE wikimedia_importance (
272 language TEXT NOT NULL,
274 importance double precision NOT NULL,
276 ) {{db.tablespace.address_data}};
279 -- osm2pgsql does not create indexes on the middle tables for Nominatim
280 -- Add one for lookup of associated street relations.
281 {% if db.middle_db_format == '1' %}
282 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts)
283 {{db.tablespace.address_index}}
284 WHERE tags @> ARRAY['associatedStreet'];
286 CREATE INDEX planet_osm_rels_relation_members_idx ON planet_osm_rels USING gin(planet_osm_member_ids(members, 'R'::character(1)))
287 WITH (fastupdate=off)
288 {{db.tablespace.address_index}};
291 -- Needed for lookups if a node is part of an interpolation.
292 CREATE INDEX IF NOT EXISTS idx_place_interpolations
293 ON place USING gist(geometry) {{db.tablespace.address_index}}
294 WHERE osm_type = 'W' and address ? 'interpolation';