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}";
38 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
39 GRANT SELECT ON TABLE us_postcode TO "{www-user}";
41 drop table IF EXISTS word;
48 country_code varchar(2),
49 search_name_count INTEGER,
52 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
53 GRANT SELECT ON word TO "{www-user}" ;
54 DROP SEQUENCE IF EXISTS seq_word;
55 CREATE SEQUENCE seq_word start 1;
57 drop table IF EXISTS location_area CASCADE;
58 CREATE TABLE location_area (
62 rank_search SMALLINT NOT NULL,
63 rank_address SMALLINT NOT NULL,
64 country_code VARCHAR(2),
67 centroid GEOMETRY(Point, 4326),
68 geometry GEOMETRY(Geometry, 4326)
71 CREATE TABLE location_area_large () INHERITS (location_area);
73 DROP TABLE IF EXISTS location_area_country;
74 CREATE TABLE location_area_country (
76 country_code varchar(2),
77 geometry GEOMETRY(Geometry, 4326)
79 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
82 drop table IF EXISTS location_property CASCADE;
83 CREATE TABLE location_property (
85 parent_place_id BIGINT,
89 centroid GEOMETRY(Point, 4326)
92 CREATE TABLE location_property_aux () INHERITS (location_property);
93 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
94 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
95 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
96 GRANT SELECT ON location_property_aux TO "{www-user}";
98 CREATE TABLE location_property_tiger (
100 parent_place_id BIGINT,
105 interpolationtype TEXT,
107 GRANT SELECT ON location_property_tiger TO "{www-user}";
109 drop table if exists location_property_osmline;
110 CREATE TABLE location_property_osmline (
111 place_id BIGINT NOT NULL,
113 parent_place_id BIGINT,
114 geometry_sector INTEGER,
115 indexed_date TIMESTAMP,
119 indexed_status SMALLINT,
121 interpolationtype TEXT,
124 country_code VARCHAR(2)
126 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
127 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
128 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
129 GRANT SELECT ON location_property_osmline TO "{www-user}";
131 drop table IF EXISTS search_name;
132 CREATE TABLE search_name (
135 search_rank SMALLINT,
136 address_rank SMALLINT,
137 name_vector integer[],
138 nameaddress_vector integer[],
139 country_code varchar(2),
140 centroid GEOMETRY(Geometry, 4326)
142 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
144 drop table IF EXISTS place_addressline;
145 CREATE TABLE place_addressline (
147 address_place_id BIGINT,
149 cached_rank_address SMALLINT,
153 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
155 drop table if exists placex;
156 CREATE TABLE placex (
157 place_id BIGINT NOT NULL,
158 parent_place_id BIGINT,
159 linked_place_id BIGINT,
161 indexed_date TIMESTAMP,
162 geometry_sector INTEGER,
163 rank_address SMALLINT,
164 rank_search SMALLINT,
166 indexed_status SMALLINT,
167 LIKE place INCLUDING CONSTRAINTS,
168 wikipedia TEXT, -- calculated wikipedia article name (language:title)
169 country_code varchar(2),
172 centroid GEOMETRY(Geometry, 4326)
174 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
175 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
176 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
177 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
178 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
179 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;
180 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;
182 DROP SEQUENCE IF EXISTS seq_place;
183 CREATE SEQUENCE seq_place start 1;
184 GRANT SELECT on placex to "{www-user}" ;
185 GRANT SELECT ON search_name to "{www-user}" ;
186 GRANT SELECT on place_addressline to "{www-user}" ;
187 GRANT SELECT ON seq_word to "{www-user}" ;
188 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
189 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
190 GRANT SELECT on location_area to "{www-user}" ;
192 -- Table for synthetic postcodes.
193 DROP TABLE IF EXISTS location_postcode;
194 CREATE TABLE location_postcode (
196 parent_place_id BIGINT,
197 rank_search SMALLINT,
198 rank_address SMALLINT,
199 indexed_status SMALLINT,
200 indexed_date TIMESTAMP,
201 country_code varchar(2),
203 geometry GEOMETRY(Geometry, 4326)
205 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
206 GRANT SELECT ON location_postcode TO "{www-user}" ;
208 DROP TABLE IF EXISTS import_polygon_error;
209 CREATE TABLE import_polygon_error (
215 country_code varchar(2),
218 prevgeometry GEOMETRY(Geometry, 4326),
219 newgeometry GEOMETRY(Geometry, 4326)
221 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
222 GRANT SELECT ON import_polygon_error TO "{www-user}";
224 DROP TABLE IF EXISTS import_polygon_delete;
225 CREATE TABLE import_polygon_delete (
231 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
232 GRANT SELECT ON import_polygon_delete TO "{www-user}";
234 DROP SEQUENCE IF EXISTS file;
235 CREATE SEQUENCE file start 1;
237 -- null table so it won't error
238 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
239 CREATE TABLE wikipedia_article (
240 language text NOT NULL,
245 lat double precision,
246 lon double precision,
247 importance double precision,
248 osm_type character(1),
253 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
254 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
256 CREATE TABLE wikipedia_redirect (
261 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
263 -- osm2pgsql does not create indexes on the middle tables for Nominatim
264 -- Add one for lookup of associated street relations.
265 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];