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 drop table if exists import_status;
9 CREATE TABLE import_status (
10 lastimportdate timestamp with time zone NOT NULL,
14 GRANT SELECT ON import_status TO "{{config.DATABASE_WEBUSER}}" ;
16 drop table if exists import_osmosis_log;
17 CREATE TABLE import_osmosis_log (
26 CREATE TABLE new_query_log (
39 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
40 GRANT INSERT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
41 GRANT UPDATE ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
42 GRANT SELECT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
44 GRANT SELECT ON TABLE country_name TO "{{config.DATABASE_WEBUSER}}";
46 DROP TABLE IF EXISTS nominatim_properties;
47 CREATE TABLE nominatim_properties (
48 property TEXT NOT NULL,
51 GRANT SELECT ON TABLE nominatim_properties TO "{{config.DATABASE_WEBUSER}}";
53 drop table IF EXISTS location_area CASCADE;
54 CREATE TABLE location_area (
58 rank_search SMALLINT NOT NULL,
59 rank_address SMALLINT NOT NULL,
60 country_code VARCHAR(2),
63 centroid GEOMETRY(Point, 4326),
64 geometry GEOMETRY(Geometry, 4326)
67 CREATE TABLE location_area_large () INHERITS (location_area);
69 DROP TABLE IF EXISTS location_area_country;
70 CREATE TABLE location_area_country (
72 country_code varchar(2),
73 geometry GEOMETRY(Geometry, 4326)
74 ) {{db.tablespace.address_data}};
75 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
78 CREATE TABLE location_property_tiger (
80 parent_place_id BIGINT,
87 GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
89 drop table if exists location_property_osmline;
90 CREATE TABLE location_property_osmline (
91 place_id BIGINT NOT NULL,
93 parent_place_id BIGINT,
94 geometry_sector INTEGER,
95 indexed_date TIMESTAMP,
100 indexed_status SMALLINT,
103 token_info JSONB, -- custom column for tokenizer use only
105 country_code VARCHAR(2)
106 ){{db.tablespace.search_data}};
107 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
108 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
109 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}}
110 WHERE startnumber is not null;
111 GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
113 drop table IF EXISTS search_name;
114 {% if not db.reverse_only %}
115 CREATE TABLE search_name (
118 search_rank SMALLINT,
119 address_rank SMALLINT,
120 name_vector integer[],
121 nameaddress_vector integer[],
122 country_code varchar(2),
123 centroid GEOMETRY(Geometry, 4326)
124 ) {{db.tablespace.search_data}};
125 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
126 GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
129 drop table IF EXISTS place_addressline;
130 CREATE TABLE place_addressline (
132 address_place_id BIGINT,
134 cached_rank_address SMALLINT,
137 ) {{db.tablespace.search_data}};
138 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
140 --------- PLACEX - storage for all indexed places -----------------
142 DROP TABLE IF EXISTS placex;
143 CREATE TABLE placex (
144 place_id BIGINT NOT NULL,
145 parent_place_id BIGINT,
146 linked_place_id BIGINT,
148 indexed_date TIMESTAMP,
149 geometry_sector INTEGER,
150 rank_address SMALLINT,
151 rank_search SMALLINT,
153 indexed_status SMALLINT,
154 LIKE place INCLUDING CONSTRAINTS,
155 wikipedia TEXT, -- calculated wikipedia article name (language:title)
156 token_info JSONB, -- custom column for tokenizer use only
157 country_code varchar(2),
160 centroid GEOMETRY(Geometry, 4326)
161 ) {{db.tablespace.search_data}};
163 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
164 {% for osm_type in ('N', 'W', 'R') %}
165 CREATE INDEX idx_placex_osmid_{{osm_type | lower}} ON placex
166 USING BTREE (osm_id) {{db.tablespace.search_index}}
167 WHERE osm_type = '{{osm_type}}';
170 -- Usage: - removing linkage status on update
171 -- - lookup linked places for /details
172 CREATE INDEX idx_placex_linked_place_id ON placex
173 USING BTREE (linked_place_id) {{db.tablespace.address_index}}
174 WHERE linked_place_id IS NOT NULL;
176 -- Usage: - check that admin boundaries do not overtake each other rank-wise
177 -- - check that place node in a admin boundary with the same address level
178 -- - boundary is not completely contained in a place area
179 -- - parenting of large-area or unparentable features
180 CREATE INDEX idx_placex_geometry_address_area_candidates ON placex
181 USING gist (geometry) {{db.tablespace.address_index}}
182 WHERE rank_address between 1 and 25
183 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
185 -- Usage: - POI is within building with housenumber
186 CREATE INDEX idx_placex_geometry_buildings ON placex
187 USING {{postgres.spgist_geom}} (geometry) {{db.tablespace.address_index}}
188 WHERE address is not null and rank_search = 30
189 and ST_GeometryType(geometry) in ('ST_Polygon','ST_MultiPolygon');
191 -- Usage: - linking of similar named places to boundaries
192 -- - linking of place nodes with same type to boundaries
193 CREATE INDEX idx_placex_geometry_placenode ON placex
194 USING {{postgres.spgist_geom}} (geometry) {{db.tablespace.address_index}}
195 WHERE osm_type = 'N' and rank_search < 26
196 and class = 'place' and type != 'postcode';
198 -- Usage: - is node part of a way?
199 -- - find parent of interpolation spatially
200 CREATE INDEX idx_placex_geometry_lower_rank_ways ON placex
201 USING {{postgres.spgist_geom}} (geometry) {{db.tablespace.address_index}}
202 WHERE osm_type = 'W' and rank_search >= 26;
204 -- Usage: - linking place nodes by wikidata tag to boundaries
205 CREATE INDEX idx_placex_wikidata on placex
206 USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}}
207 WHERE extratags ? 'wikidata' and class = 'place'
208 and osm_type = 'N' and rank_search < 26;
210 -- The following two indexes function as a todo list for indexing.
212 CREATE INDEX idx_placex_rank_address_sector ON placex
213 USING BTREE (rank_address, geometry_sector) {{db.tablespace.address_index}}
214 WHERE indexed_status > 0;
216 CREATE INDEX idx_placex_rank_boundaries_sector ON placex
217 USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}}
218 WHERE class = 'boundary' and type = 'administrative'
219 and indexed_status > 0;
222 DROP SEQUENCE IF EXISTS seq_place;
223 CREATE SEQUENCE seq_place start 1;
224 GRANT SELECT on placex to "{{config.DATABASE_WEBUSER}}" ;
225 GRANT SELECT on place_addressline to "{{config.DATABASE_WEBUSER}}" ;
226 GRANT SELECT ON planet_osm_ways to "{{config.DATABASE_WEBUSER}}" ;
227 GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
228 GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
230 -- Table for synthetic postcodes.
231 DROP TABLE IF EXISTS location_postcode;
232 CREATE TABLE location_postcode (
234 parent_place_id BIGINT,
235 rank_search SMALLINT,
236 rank_address SMALLINT,
237 indexed_status SMALLINT,
238 indexed_date TIMESTAMP,
239 country_code varchar(2),
241 geometry GEOMETRY(Geometry, 4326)
243 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {{db.tablespace.search_index}};
244 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
245 GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
247 DROP TABLE IF EXISTS import_polygon_error;
248 CREATE TABLE import_polygon_error (
254 country_code varchar(2),
257 prevgeometry GEOMETRY(Geometry, 4326),
258 newgeometry GEOMETRY(Geometry, 4326)
260 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
261 GRANT SELECT ON import_polygon_error TO "{{config.DATABASE_WEBUSER}}";
263 DROP TABLE IF EXISTS import_polygon_delete;
264 CREATE TABLE import_polygon_delete (
270 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
271 GRANT SELECT ON import_polygon_delete TO "{{config.DATABASE_WEBUSER}}";
273 DROP SEQUENCE IF EXISTS file;
274 CREATE SEQUENCE file start 1;
276 -- null table so it won't error
277 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
278 CREATE TABLE IF NOT EXISTS wikipedia_article (
279 language text NOT NULL,
284 lat double precision,
285 lon double precision,
286 importance double precision,
287 osm_type character(1),
293 CREATE TABLE IF NOT EXISTS wikipedia_redirect (
299 -- osm2pgsql does not create indexes on the middle tables for Nominatim
300 -- Add one for lookup of associated street relations.
301 {% if db.middle_db_format == '1' %}
302 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts)
303 {{db.tablespace.address_index}}
304 WHERE tags @> ARRAY['associatedStreet'];
306 CREATE INDEX planet_osm_rels_relation_members_idx ON planet_osm_rels USING gin(planet_osm_member_ids(members, 'R'::character(1)))
307 WITH (fastupdate=off)
308 {{db.tablespace.address_index}};
311 -- Needed for lookups if a node is part of an interpolation.
312 CREATE INDEX IF NOT EXISTS idx_place_interpolations
313 ON place USING gist(geometry) {{db.tablespace.address_index}}
314 WHERE osm_type = 'W' and address ? 'interpolation';
316 GRANT SELECT ON table country_osm_grid to "{{config.DATABASE_WEBUSER}}";