1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp with time zone NOT NULL,
7 GRANT SELECT ON import_status TO "{{config.DATABASE_WEBUSER}}" ;
9 drop table if exists import_osmosis_log;
10 CREATE TABLE import_osmosis_log (
19 CREATE TABLE new_query_log (
32 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
33 GRANT INSERT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
34 GRANT UPDATE ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
35 GRANT SELECT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
37 GRANT SELECT ON TABLE country_name TO "{{config.DATABASE_WEBUSER}}";
39 DROP TABLE IF EXISTS nominatim_properties;
40 CREATE TABLE nominatim_properties (
44 GRANT SELECT ON TABLE nominatim_properties TO "{{config.DATABASE_WEBUSER}}";
46 drop table IF EXISTS word;
53 country_code varchar(2),
54 search_name_count INTEGER,
56 ) {{db.tablespace.search_data}};
57 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {{db.tablespace.search_index}};
58 GRANT SELECT ON word TO "{{config.DATABASE_WEBUSER}}" ;
59 DROP SEQUENCE IF EXISTS seq_word;
60 CREATE SEQUENCE seq_word start 1;
62 drop table IF EXISTS location_area CASCADE;
63 CREATE TABLE location_area (
67 rank_search SMALLINT NOT NULL,
68 rank_address SMALLINT NOT NULL,
69 country_code VARCHAR(2),
72 centroid GEOMETRY(Point, 4326),
73 geometry GEOMETRY(Geometry, 4326)
76 CREATE TABLE location_area_large () INHERITS (location_area);
78 DROP TABLE IF EXISTS location_area_country;
79 CREATE TABLE location_area_country (
81 country_code varchar(2),
82 geometry GEOMETRY(Geometry, 4326)
83 ) {{db.tablespace.address_data}};
84 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
87 drop table IF EXISTS location_property CASCADE;
88 CREATE TABLE location_property (
90 parent_place_id BIGINT,
94 centroid GEOMETRY(Point, 4326)
97 CREATE TABLE location_property_aux () INHERITS (location_property);
98 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
99 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
100 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
101 GRANT SELECT ON location_property_aux TO "{{config.DATABASE_WEBUSER}}";
103 CREATE TABLE location_property_tiger (
105 parent_place_id BIGINT,
110 interpolationtype TEXT,
112 GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
114 drop table if exists location_property_osmline;
115 CREATE TABLE location_property_osmline (
116 place_id BIGINT NOT NULL,
118 parent_place_id BIGINT,
119 geometry_sector INTEGER,
120 indexed_date TIMESTAMP,
124 indexed_status SMALLINT,
126 interpolationtype TEXT,
129 country_code VARCHAR(2)
130 ){{db.tablespace.search_data}};
131 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
132 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
133 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}};
134 GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
136 drop table IF EXISTS search_name;
137 {% if not db.reverse_only %}
138 CREATE TABLE search_name (
141 search_rank SMALLINT,
142 address_rank SMALLINT,
143 name_vector integer[],
144 nameaddress_vector integer[],
145 country_code varchar(2),
146 centroid GEOMETRY(Geometry, 4326)
147 ) {{db.tablespace.search_data}};
148 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
149 GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
152 drop table IF EXISTS place_addressline;
153 CREATE TABLE place_addressline (
155 address_place_id BIGINT,
157 cached_rank_address SMALLINT,
160 ) {{db.tablespace.search_data}};
161 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
163 drop table if exists placex;
164 CREATE TABLE placex (
165 place_id BIGINT NOT NULL,
166 parent_place_id BIGINT,
167 linked_place_id BIGINT,
169 indexed_date TIMESTAMP,
170 geometry_sector INTEGER,
171 rank_address SMALLINT,
172 rank_search SMALLINT,
174 indexed_status SMALLINT,
175 LIKE place INCLUDING CONSTRAINTS,
176 wikipedia TEXT, -- calculated wikipedia article name (language:title)
177 country_code varchar(2),
180 centroid GEOMETRY(Geometry, 4326)
181 ) {{db.tablespace.search_data}};
182 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
183 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {{db.tablespace.search_index}};
184 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {{db.tablespace.address_index}} WHERE linked_place_id IS NOT NULL;
185 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}};
186 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {{db.tablespace.search_index}};
187 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name')) {{db.tablespace.address_index}} WHERE osm_type='N' and rank_search < 26;
188 CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
190 DROP SEQUENCE IF EXISTS seq_place;
191 CREATE SEQUENCE seq_place start 1;
192 GRANT SELECT on placex to "{{config.DATABASE_WEBUSER}}" ;
193 GRANT SELECT on place_addressline to "{{config.DATABASE_WEBUSER}}" ;
194 GRANT SELECT ON seq_word to "{{config.DATABASE_WEBUSER}}" ;
195 GRANT SELECT ON planet_osm_ways to "{{config.DATABASE_WEBUSER}}" ;
196 GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
197 GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
199 -- Table for synthetic postcodes.
200 DROP TABLE IF EXISTS location_postcode;
201 CREATE TABLE location_postcode (
203 parent_place_id BIGINT,
204 rank_search SMALLINT,
205 rank_address SMALLINT,
206 indexed_status SMALLINT,
207 indexed_date TIMESTAMP,
208 country_code varchar(2),
210 geometry GEOMETRY(Geometry, 4326)
212 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
213 GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
215 DROP TABLE IF EXISTS import_polygon_error;
216 CREATE TABLE import_polygon_error (
222 country_code varchar(2),
225 prevgeometry GEOMETRY(Geometry, 4326),
226 newgeometry GEOMETRY(Geometry, 4326)
228 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
229 GRANT SELECT ON import_polygon_error TO "{{config.DATABASE_WEBUSER}}";
231 DROP TABLE IF EXISTS import_polygon_delete;
232 CREATE TABLE import_polygon_delete (
238 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
239 GRANT SELECT ON import_polygon_delete TO "{{config.DATABASE_WEBUSER}}";
241 DROP SEQUENCE IF EXISTS file;
242 CREATE SEQUENCE file start 1;
244 -- null table so it won't error
245 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
246 CREATE TABLE wikipedia_article (
247 language text NOT NULL,
252 lat double precision,
253 lon double precision,
254 importance double precision,
255 osm_type character(1),
260 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
261 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
263 CREATE TABLE wikipedia_redirect (
268 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
270 -- osm2pgsql does not create indexes on the middle tables for Nominatim
271 -- Add one for lookup of associated street relations.
272 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];