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;
61 country_code varchar(2),
62 search_name_count INTEGER,
65 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) TABLESPACE ssd;
66 GRANT SELECT ON word TO "www-data" ;
67 DROP SEQUENCE seq_word;
68 CREATE SEQUENCE seq_word start 1;
70 drop table IF EXISTS location_area CASCADE;
71 CREATE TABLE location_area (
74 country_code VARCHAR(2),
76 rank_search INTEGER NOT NULL,
77 rank_address INTEGER NOT NULL,
80 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
81 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
83 CREATE TABLE location_area_large () INHERITS (location_area);
84 CREATE TABLE location_area_roadnear () INHERITS (location_area);
85 CREATE TABLE location_area_roadfar () INHERITS (location_area);
87 drop table IF EXISTS location_property CASCADE;
88 CREATE TABLE location_property (
91 parent_place_id BIGINT,
95 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
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-data";
103 CREATE TABLE location_property_tiger () INHERITS (location_property);
104 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
105 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
106 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
107 GRANT SELECT ON location_property_tiger TO "www-data";
109 drop table IF EXISTS search_name;
110 CREATE TABLE search_name (
113 address_rank integer,
115 country_code varchar(2),
116 name_vector integer[],
117 nameaddress_vector integer[]
119 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
120 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) TABLESPACE ssd;
122 drop table IF EXISTS place_addressline;
123 CREATE TABLE place_addressline (
125 address_place_id BIGINT,
129 cached_rank_address integer
131 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) TABLESPACE ssd;
133 drop table IF EXISTS place_boundingbox CASCADE;
134 CREATE TABLE place_boundingbox (
143 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
144 GRANT SELECT on place_boundingbox to "www-data" ;
145 GRANT INSERT on place_boundingbox to "www-data" ;
147 drop table IF EXISTS reverse_cache;
148 CREATE TABLE reverse_cache (
149 latlonzoomid integer,
150 country_code varchar(2),
153 GRANT SELECT on reverse_cache to "www-data" ;
154 GRANT INSERT on reverse_cache to "www-data" ;
155 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
158 CREATE TABLE country (
159 country_code varchar(2),
161 country_default_language_code varchar(2)
163 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
164 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
165 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
166 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
167 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
170 CREATE TABLE placex (
171 place_id BIGINT NOT NULL,
173 LIKE place INCLUDING CONSTRAINTS,
174 parent_place_id BIGINT,
175 linked_place_id BIGINT,
176 rank_address INTEGER,
179 indexed_status INTEGER,
180 indexed_date TIMESTAMP,
181 wikipedia TEXT, -- calculated wikipedia article name (language:title)
182 geometry_sector INTEGER,
183 calculated_country_code varchar(2)
185 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
186 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) TABLESPACE ssd;
187 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) TABLESPACE ssd;
188 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) TABLESPACE ssd;
189 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) TABLESPACE ssd;
190 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) TABLESPACE ssd;
191 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;
193 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
195 --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;
197 DROP SEQUENCE seq_place;
198 CREATE SEQUENCE seq_place start 1;
199 GRANT SELECT on placex to "www-data" ;
200 GRANT SELECT ON search_name to "www-data" ;
201 GRANT SELECT on place_addressline to "www-data" ;
202 GRANT SELECT ON seq_word to "www-data" ;
203 GRANT SELECT ON planet_osm_ways to "www-data" ;
204 GRANT SELECT ON planet_osm_rels to "www-data" ;
205 GRANT SELECT on location_area to "www-data" ;
206 GRANT SELECT on country to "www-data" ;
208 -- insert creates the location tagbles, creates location indexes if indexed == true
209 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
210 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
212 -- update insert creates the location tables
213 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
214 FOR EACH ROW EXECUTE PROCEDURE placex_update();
216 -- diff update triggers
217 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
218 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
219 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
220 FOR EACH ROW EXECUTE PROCEDURE place_delete();
221 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
222 FOR EACH ROW EXECUTE PROCEDURE place_insert();
224 drop index idx_placex_sector;
225 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) TABLESPACE ssd;
227 DROP SEQUENCE seq_postcodes;
228 CREATE SEQUENCE seq_postcodes start 1;
230 drop table import_polygon_error;
231 CREATE TABLE import_polygon_error (
237 country_code varchar(2),
241 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
242 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
243 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id) TABLESPACE ssd;
244 GRANT SELECT ON import_polygon_error TO "www-data";
246 drop table import_polygon_delete;
247 CREATE TABLE import_polygon_delete (
253 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id) TABLESPACE ssd;
254 GRANT SELECT ON import_polygon_delete TO "www-data";
257 CREATE SEQUENCE file start 1;
259 -- null table so it won't error
260 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
261 CREATE TABLE wikipedia_article (
262 language text NOT NULL,
267 lat double precision,
268 lon double precision,
269 importance double precision,
270 osm_type character(1),
273 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
274 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
276 CREATE TABLE wikipedia_redirect (
281 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);