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 word;
46 country_code varchar(2),
47 search_name_count INTEGER,
50 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
51 GRANT SELECT ON word TO "{www-user}" ;
52 DROP SEQUENCE IF EXISTS seq_word;
53 CREATE SEQUENCE seq_word start 1;
55 drop table IF EXISTS location_area CASCADE;
56 CREATE TABLE location_area (
60 rank_search SMALLINT NOT NULL,
61 rank_address SMALLINT NOT NULL,
62 country_code VARCHAR(2),
65 centroid GEOMETRY(Point, 4326),
66 geometry GEOMETRY(Geometry, 4326)
69 CREATE TABLE location_area_large () INHERITS (location_area);
71 DROP TABLE IF EXISTS location_area_country;
72 CREATE TABLE location_area_country (
74 country_code varchar(2),
75 geometry GEOMETRY(Geometry, 4326)
77 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
80 drop table IF EXISTS location_property CASCADE;
81 CREATE TABLE location_property (
83 parent_place_id BIGINT,
87 centroid GEOMETRY(Point, 4326)
90 CREATE TABLE location_property_aux () INHERITS (location_property);
91 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
92 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
93 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
94 GRANT SELECT ON location_property_aux TO "{www-user}";
96 CREATE TABLE location_property_tiger (
98 parent_place_id BIGINT,
103 interpolationtype TEXT,
105 GRANT SELECT ON location_property_tiger TO "{www-user}";
107 drop table if exists location_property_osmline;
108 CREATE TABLE location_property_osmline (
109 place_id BIGINT NOT NULL,
111 parent_place_id BIGINT,
112 geometry_sector INTEGER,
113 indexed_date TIMESTAMP,
117 indexed_status SMALLINT,
119 interpolationtype TEXT,
122 country_code VARCHAR(2)
124 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
125 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
126 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
127 GRANT SELECT ON location_property_osmline TO "{www-user}";
129 drop table IF EXISTS search_name;
130 CREATE TABLE search_name (
133 search_rank SMALLINT,
134 address_rank SMALLINT,
135 name_vector integer[],
136 nameaddress_vector integer[],
137 country_code varchar(2),
138 centroid GEOMETRY(Geometry, 4326)
140 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
142 drop table IF EXISTS place_addressline;
143 CREATE TABLE place_addressline (
145 address_place_id BIGINT,
147 cached_rank_address SMALLINT,
151 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
153 drop table if exists placex;
154 CREATE TABLE placex (
155 place_id BIGINT NOT NULL,
156 parent_place_id BIGINT,
157 linked_place_id BIGINT,
159 indexed_date TIMESTAMP,
160 geometry_sector INTEGER,
161 rank_address SMALLINT,
162 rank_search SMALLINT,
164 indexed_status SMALLINT,
165 LIKE place INCLUDING CONSTRAINTS,
166 wikipedia TEXT, -- calculated wikipedia article name (language:title)
167 country_code varchar(2),
170 centroid GEOMETRY(Geometry, 4326)
172 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
173 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
174 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
175 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
176 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
177 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;
178 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;
180 DROP SEQUENCE IF EXISTS seq_place;
181 CREATE SEQUENCE seq_place start 1;
182 GRANT SELECT on placex to "{www-user}" ;
183 GRANT SELECT ON search_name to "{www-user}" ;
184 GRANT SELECT on place_addressline to "{www-user}" ;
185 GRANT SELECT ON seq_word to "{www-user}" ;
186 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
187 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
188 GRANT SELECT on location_area to "{www-user}" ;
190 -- Table for synthetic postcodes.
191 DROP TABLE IF EXISTS location_postcode;
192 CREATE TABLE location_postcode (
194 parent_place_id BIGINT,
195 rank_search SMALLINT,
196 rank_address SMALLINT,
197 indexed_status SMALLINT,
198 indexed_date TIMESTAMP,
199 country_code varchar(2),
201 geometry GEOMETRY(Geometry, 4326)
203 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
204 GRANT SELECT ON location_postcode TO "{www-user}" ;
206 DROP TABLE IF EXISTS import_polygon_error;
207 CREATE TABLE import_polygon_error (
213 country_code varchar(2),
216 prevgeometry GEOMETRY(Geometry, 4326),
217 newgeometry GEOMETRY(Geometry, 4326)
219 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
220 GRANT SELECT ON import_polygon_error TO "{www-user}";
222 DROP TABLE IF EXISTS import_polygon_delete;
223 CREATE TABLE import_polygon_delete (
229 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
230 GRANT SELECT ON import_polygon_delete TO "{www-user}";
232 DROP SEQUENCE IF EXISTS file;
233 CREATE SEQUENCE file start 1;
235 -- null table so it won't error
236 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
237 CREATE TABLE wikipedia_article (
238 language text NOT NULL,
243 lat double precision,
244 lon double precision,
245 importance double precision,
246 osm_type character(1),
251 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
252 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
254 CREATE TABLE wikipedia_redirect (
259 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
261 -- osm2pgsql does not create indexes on the middle tables for Nominatim
262 -- Add one for lookup of associated street relations.
263 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];