1 drop table import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL
5 GRANT SELECT ON import_status TO "www-data" ;
7 drop table import_osmosis_log;
8 CREATE TABLE import_osmosis_log (
16 drop table import_npi_log;
17 CREATE TABLE import_npi_log (
26 CREATE TABLE new_query_log (
39 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
40 GRANT INSERT ON new_query_log TO "www-data" ;
41 GRANT UPDATE ON new_query_log TO "www-data" ;
42 GRANT SELECT ON new_query_log TO "www-data" ;
44 --drop table IF EXISTS report_log;
45 CREATE TABLE report_log (
52 GRANT INSERT ON report_log TO "www-data" ;
54 drop table IF EXISTS word;
62 country_code varchar(2),
63 search_name_count INTEGER,
66 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
67 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) TABLESPACE ssd;
68 --CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops) WITH (fastupdate = off);
69 GRANT SELECT ON word TO "www-data" ;
70 DROP SEQUENCE seq_word;
71 CREATE SEQUENCE seq_word start 1;
73 drop table IF EXISTS location_area CASCADE;
74 CREATE TABLE location_area (
77 country_code VARCHAR(2),
79 rank_search INTEGER NOT NULL,
80 rank_address INTEGER NOT NULL,
83 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
84 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
86 CREATE TABLE location_area_large () INHERITS (location_area);
87 CREATE TABLE location_area_roadnear () INHERITS (location_area);
88 CREATE TABLE location_area_roadfar () INHERITS (location_area);
90 drop table IF EXISTS location_property CASCADE;
91 CREATE TABLE location_property (
94 parent_place_id BIGINT,
98 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
100 CREATE TABLE location_property_aux () INHERITS (location_property);
101 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
102 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
103 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
104 GRANT SELECT ON location_property_aux TO "www-data";
106 CREATE TABLE location_property_tiger () INHERITS (location_property);
107 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
108 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
109 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
110 GRANT SELECT ON location_property_tiger TO "www-data";
112 drop table IF EXISTS search_name_blank CASCADE;
113 CREATE TABLE search_name_blank (
116 address_rank integer,
118 country_code varchar(2),
119 name_vector integer[],
120 nameaddress_vector integer[]
122 SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
124 drop table IF EXISTS search_name;
125 CREATE TABLE search_name () INHERITS (search_name_blank) TABLESPACE ssd;
126 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) TABLESPACE ssd;
128 drop table IF EXISTS place_addressline;
129 CREATE TABLE place_addressline (
131 address_place_id BIGINT,
135 cached_rank_address integer
137 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) TABLESPACE ssd;
139 drop table IF EXISTS place_boundingbox CASCADE;
140 CREATE TABLE place_boundingbox (
149 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
150 GRANT SELECT on place_boundingbox to "www-data" ;
151 GRANT INSERT on place_boundingbox to "www-data" ;
153 drop table IF EXISTS reverse_cache;
154 CREATE TABLE reverse_cache (
155 latlonzoomid integer,
156 country_code varchar(2),
159 GRANT SELECT on reverse_cache to "www-data" ;
160 GRANT INSERT on reverse_cache to "www-data" ;
161 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
164 CREATE TABLE country (
165 country_code varchar(2),
167 country_default_language_code varchar(2)
169 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
170 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
171 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
172 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
173 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
176 CREATE TABLE placex (
177 place_id BIGINT NOT NULL,
179 LIKE place INCLUDING CONSTRAINTS,
180 parent_place_id BIGINT,
181 linked_place_id BIGINT,
182 rank_address INTEGER,
185 indexed_status INTEGER,
186 indexed_date TIMESTAMP,
187 wikipedia TEXT, -- calculated wikipedia article name (language:title)
188 geometry_sector INTEGER,
189 calculated_country_code varchar(2)
191 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
192 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) TABLESPACE ssd;
193 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) TABLESPACE ssd;
194 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) TABLESPACE ssd;
195 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) TABLESPACE ssd;
196 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) TABLESPACE ssd;
197 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) TABLESPACE ssd WHERE osm_type='N' and rank_search < 26;
199 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
201 --CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search) where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
203 DROP SEQUENCE seq_place;
204 CREATE SEQUENCE seq_place start 1;
205 GRANT SELECT on placex to "www-data" ;
206 GRANT UPDATE ON placex to "www-data" ;
207 GRANT SELECT ON search_name to "www-data" ;
208 GRANT DELETE on search_name to "www-data" ;
209 GRANT INSERT on search_name to "www-data" ;
210 GRANT SELECT on place_addressline to "www-data" ;
211 GRANT INSERT ON place_addressline to "www-data" ;
212 GRANT DELETE on place_addressline to "www-data" ;
213 GRANT SELECT ON seq_word to "www-data" ;
214 GRANT UPDATE ON seq_word to "www-data" ;
215 GRANT INSERT ON word to "www-data" ;
216 GRANT SELECT ON planet_osm_ways to "www-data" ;
217 GRANT SELECT ON planet_osm_rels to "www-data" ;
218 GRANT SELECT on location_area to "www-data" ;
219 GRANT SELECT on country to "www-data" ;
221 -- insert creates the location tagbles, creates location indexes if indexed == true
222 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
223 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
225 -- update insert creates the location tables
226 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
227 FOR EACH ROW EXECUTE PROCEDURE placex_update();
229 -- diff update triggers
230 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
231 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
232 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
233 FOR EACH ROW EXECUTE PROCEDURE place_delete();
234 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
235 FOR EACH ROW EXECUTE PROCEDURE place_insert();
237 alter table placex add column geometry_sector INTEGER;
238 alter table placex add column indexed_status INTEGER;
239 alter table placex add column indexed_date TIMESTAMP;
241 update placex set geometry_sector = geometry_sector(geometry);
242 drop index idx_placex_pendingbylatlon;
243 drop index idx_placex_interpolation;
244 drop index idx_placex_sector;
245 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search) TABLESPACE ssd
246 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
247 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) TABLESPACE ssd where indexed = false and class='place' and type='houses';
248 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) TABLESPACE ssd;
250 DROP SEQUENCE seq_postcodes;
251 CREATE SEQUENCE seq_postcodes start 1;
253 drop table import_polygon_error;
254 CREATE TABLE import_polygon_error (
260 country_code varchar(2),
264 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
265 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
266 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id) TABLESPACE ssd;
268 drop table import_polygon_delete;
269 CREATE TABLE import_polygon_delete (
275 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id) TABLESPACE ssd;
278 CREATE SEQUENCE file start 1;
280 -- null table so it won't error
281 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
282 CREATE TABLE wikipedia_article (
283 language text NOT NULL,
288 lat double precision,
289 lon double precision,
290 importance double precision,
291 osm_type character(1),
294 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
295 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
297 CREATE TABLE wikipedia_redirect (
302 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);