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 CREATE TABLE location_property_tiger (
89 parent_place_id BIGINT,
94 interpolationtype TEXT,
96 GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
98 drop table if exists location_property_osmline;
99 CREATE TABLE location_property_osmline (
100 place_id BIGINT NOT NULL,
102 parent_place_id BIGINT,
103 geometry_sector INTEGER,
104 indexed_date TIMESTAMP,
108 indexed_status SMALLINT,
110 interpolationtype TEXT,
113 country_code VARCHAR(2)
114 ){{db.tablespace.search_data}};
115 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
116 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
117 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}};
118 GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
120 drop table IF EXISTS search_name;
121 {% if not db.reverse_only %}
122 CREATE TABLE search_name (
125 search_rank SMALLINT,
126 address_rank SMALLINT,
127 name_vector integer[],
128 nameaddress_vector integer[],
129 country_code varchar(2),
130 centroid GEOMETRY(Geometry, 4326)
131 ) {{db.tablespace.search_data}};
132 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
133 GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
136 drop table IF EXISTS place_addressline;
137 CREATE TABLE place_addressline (
139 address_place_id BIGINT,
141 cached_rank_address SMALLINT,
144 ) {{db.tablespace.search_data}};
145 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
147 drop table if exists placex;
148 CREATE TABLE placex (
149 place_id BIGINT NOT NULL,
150 parent_place_id BIGINT,
151 linked_place_id BIGINT,
153 indexed_date TIMESTAMP,
154 geometry_sector INTEGER,
155 rank_address SMALLINT,
156 rank_search SMALLINT,
158 indexed_status SMALLINT,
159 LIKE place INCLUDING CONSTRAINTS,
160 wikipedia TEXT, -- calculated wikipedia article name (language:title)
161 country_code varchar(2),
164 centroid GEOMETRY(Geometry, 4326)
165 ) {{db.tablespace.search_data}};
166 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
167 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {{db.tablespace.search_index}};
168 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;
169 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}};
170 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {{db.tablespace.search_index}};
171 CREATE INDEX idx_placex_geometry_placenode ON placex
172 USING GIST (geometry) {{db.tablespace.search_index}}
173 WHERE osm_type = 'N' and rank_search < 26
174 and class = 'place' and type != 'postcode' and linked_place_id is null;
175 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;
177 DROP SEQUENCE IF EXISTS seq_place;
178 CREATE SEQUENCE seq_place start 1;
179 GRANT SELECT on placex to "{{config.DATABASE_WEBUSER}}" ;
180 GRANT SELECT on place_addressline to "{{config.DATABASE_WEBUSER}}" ;
181 GRANT SELECT ON seq_word to "{{config.DATABASE_WEBUSER}}" ;
182 GRANT SELECT ON planet_osm_ways to "{{config.DATABASE_WEBUSER}}" ;
183 GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
184 GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
186 -- Table for synthetic postcodes.
187 DROP TABLE IF EXISTS location_postcode;
188 CREATE TABLE location_postcode (
190 parent_place_id BIGINT,
191 rank_search SMALLINT,
192 rank_address SMALLINT,
193 indexed_status SMALLINT,
194 indexed_date TIMESTAMP,
195 country_code varchar(2),
197 geometry GEOMETRY(Geometry, 4326)
199 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {{db.tablespace.search_index}};
200 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
201 GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
203 DROP TABLE IF EXISTS import_polygon_error;
204 CREATE TABLE import_polygon_error (
210 country_code varchar(2),
213 prevgeometry GEOMETRY(Geometry, 4326),
214 newgeometry GEOMETRY(Geometry, 4326)
216 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
217 GRANT SELECT ON import_polygon_error TO "{{config.DATABASE_WEBUSER}}";
219 DROP TABLE IF EXISTS import_polygon_delete;
220 CREATE TABLE import_polygon_delete (
226 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
227 GRANT SELECT ON import_polygon_delete TO "{{config.DATABASE_WEBUSER}}";
229 DROP SEQUENCE IF EXISTS file;
230 CREATE SEQUENCE file start 1;
232 -- null table so it won't error
233 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
234 CREATE TABLE wikipedia_article (
235 language text NOT NULL,
240 lat double precision,
241 lon double precision,
242 importance double precision,
243 osm_type character(1),
248 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
249 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
251 CREATE TABLE wikipedia_redirect (
256 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
258 -- osm2pgsql does not create indexes on the middle tables for Nominatim
259 -- Add one for lookup of associated street relations.
260 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];
262 GRANT SELECT ON table country_osm_grid to "{{config.DATABASE_WEBUSER}}";