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 "{www-user}" ;
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 "{www-user}" ;
34 GRANT UPDATE ON new_query_log TO "{www-user}" ;
35 GRANT SELECT ON new_query_log TO "{www-user}" ;
37 GRANT SELECT ON TABLE country_name TO "{www-user}";
39 DROP TABLE IF EXISTS nominatim_properties;
40 CREATE TABLE nominatim_properties (
44 GRANT SELECT ON TABLE nominatim_properties TO "{www-user}";
46 drop table IF EXISTS word;
53 country_code varchar(2),
54 search_name_count INTEGER,
57 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
58 GRANT SELECT ON word TO "{www-user}" ;
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)
84 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts: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 "{www-user}";
103 CREATE TABLE location_property_tiger (
105 parent_place_id BIGINT,
110 interpolationtype TEXT,
112 GRANT SELECT ON location_property_tiger TO "{www-user}";
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)
131 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
132 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
133 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
134 GRANT SELECT ON location_property_osmline TO "{www-user}";
136 drop table IF EXISTS search_name;
137 CREATE TABLE search_name (
140 search_rank SMALLINT,
141 address_rank SMALLINT,
142 name_vector integer[],
143 nameaddress_vector integer[],
144 country_code varchar(2),
145 centroid GEOMETRY(Geometry, 4326)
147 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
149 drop table IF EXISTS place_addressline;
150 CREATE TABLE place_addressline (
152 address_place_id BIGINT,
154 cached_rank_address SMALLINT,
158 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
160 drop table if exists placex;
161 CREATE TABLE placex (
162 place_id BIGINT NOT NULL,
163 parent_place_id BIGINT,
164 linked_place_id BIGINT,
166 indexed_date TIMESTAMP,
167 geometry_sector INTEGER,
168 rank_address SMALLINT,
169 rank_search SMALLINT,
171 indexed_status SMALLINT,
172 LIKE place INCLUDING CONSTRAINTS,
173 wikipedia TEXT, -- calculated wikipedia article name (language:title)
174 country_code varchar(2),
177 centroid GEOMETRY(Geometry, 4326)
179 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
180 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
181 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
182 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
183 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
184 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name')) {ts:address-index} WHERE osm_type='N' and rank_search < 26;
185 CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {ts:address-index} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
187 DROP SEQUENCE IF EXISTS seq_place;
188 CREATE SEQUENCE seq_place start 1;
189 GRANT SELECT on placex to "{www-user}" ;
190 GRANT SELECT ON search_name to "{www-user}" ;
191 GRANT SELECT on place_addressline to "{www-user}" ;
192 GRANT SELECT ON seq_word to "{www-user}" ;
193 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
194 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
195 GRANT SELECT on location_area to "{www-user}" ;
197 -- Table for synthetic postcodes.
198 DROP TABLE IF EXISTS location_postcode;
199 CREATE TABLE location_postcode (
201 parent_place_id BIGINT,
202 rank_search SMALLINT,
203 rank_address SMALLINT,
204 indexed_status SMALLINT,
205 indexed_date TIMESTAMP,
206 country_code varchar(2),
208 geometry GEOMETRY(Geometry, 4326)
210 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
211 GRANT SELECT ON location_postcode TO "{www-user}" ;
213 DROP TABLE IF EXISTS import_polygon_error;
214 CREATE TABLE import_polygon_error (
220 country_code varchar(2),
223 prevgeometry GEOMETRY(Geometry, 4326),
224 newgeometry GEOMETRY(Geometry, 4326)
226 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
227 GRANT SELECT ON import_polygon_error TO "{www-user}";
229 DROP TABLE IF EXISTS import_polygon_delete;
230 CREATE TABLE import_polygon_delete (
236 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
237 GRANT SELECT ON import_polygon_delete TO "{www-user}";
239 DROP SEQUENCE IF EXISTS file;
240 CREATE SEQUENCE file start 1;
242 -- null table so it won't error
243 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
244 CREATE TABLE wikipedia_article (
245 language text NOT NULL,
250 lat double precision,
251 lon double precision,
252 importance double precision,
253 osm_type character(1),
258 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
259 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
261 CREATE TABLE wikipedia_redirect (
266 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
268 -- osm2pgsql does not create indexes on the middle tables for Nominatim
269 -- Add one for lookup of associated street relations.
270 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];