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 --drop table IF EXISTS query_log;
27 CREATE TABLE query_log (
34 CREATE INDEX idx_query_log ON query_log USING BTREE (starttime);
35 GRANT SELECT ON query_log TO "www-data" ;
36 GRANT INSERT ON query_log TO "www-data" ;
37 GRANT UPDATE ON query_log TO "www-data" ;
39 CREATE TABLE new_query_log (
51 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
52 GRANT INSERT ON new_query_log TO "www-data" ;
53 GRANT UPDATE ON new_query_log TO "www-data" ;
54 GRANT SELECT ON new_query_log TO "www-data" ;
56 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
57 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
59 --drop table IF EXISTS report_log;
60 CREATE TABLE report_log (
67 GRANT INSERT ON report_log TO "www-data" ;
69 drop table IF EXISTS word;
77 country_code varchar(2),
78 search_name_count INTEGER,
81 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
82 CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
83 --CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops) WITH (fastupdate = off);
84 GRANT SELECT ON word TO "www-data" ;
85 DROP SEQUENCE seq_word;
86 CREATE SEQUENCE seq_word start 1;
88 drop table IF EXISTS location_area CASCADE;
89 CREATE TABLE location_area (
92 country_code VARCHAR(2),
94 rank_search INTEGER NOT NULL,
95 rank_address INTEGER NOT NULL,
98 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
99 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
101 CREATE TABLE location_area_large () INHERITS (location_area);
102 CREATE TABLE location_area_roadnear () INHERITS (location_area);
103 CREATE TABLE location_area_roadfar () INHERITS (location_area);
105 drop table IF EXISTS location_property CASCADE;
106 CREATE TABLE location_property (
109 parent_place_id BIGINT,
113 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
115 CREATE TABLE location_property_aux () INHERITS (location_property);
116 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
117 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
118 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
119 GRANT SELECT ON location_property_aux TO "www-data";
121 CREATE TABLE location_property_tiger () INHERITS (location_property);
122 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
123 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
124 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
125 GRANT SELECT ON location_property_tiger TO "www-data";
127 drop table IF EXISTS search_name_blank CASCADE;
128 CREATE TABLE search_name_blank (
131 address_rank integer,
133 country_code varchar(2),
134 name_vector integer[],
135 nameaddress_vector integer[]
137 SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
139 drop table IF EXISTS search_name;
140 CREATE TABLE search_name () INHERITS (search_name_blank);
141 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
143 drop table IF EXISTS place_addressline;
144 CREATE TABLE place_addressline (
146 address_place_id BIGINT,
150 cached_rank_address integer
152 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
154 drop table IF EXISTS place_boundingbox CASCADE;
155 CREATE TABLE place_boundingbox (
164 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
165 GRANT SELECT on place_boundingbox to "www-data" ;
166 GRANT INSERT on place_boundingbox to "www-data" ;
168 drop table IF EXISTS reverse_cache;
169 CREATE TABLE reverse_cache (
170 latlonzoomid integer,
171 country_code varchar(2),
174 GRANT SELECT on reverse_cache to "www-data" ;
175 GRANT INSERT on reverse_cache to "www-data" ;
176 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
179 CREATE TABLE country (
180 country_code varchar(2),
182 country_default_language_code varchar(2)
184 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
185 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
186 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
187 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
188 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
191 CREATE TABLE placex (
192 place_id BIGINT NOT NULL,
194 LIKE place INCLUDING CONSTRAINTS,
195 parent_place_id BIGINT,
196 linked_place_id BIGINT,
197 rank_address INTEGER,
200 indexed_status INTEGER,
201 indexed_date TIMESTAMP,
202 wikipedia TEXT, -- calculated wikipedia article name (language:title)
203 geometry_sector INTEGER,
204 calculated_country_code varchar(2)
206 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
207 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
208 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
209 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id);
210 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector);
211 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
212 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) WHERE osm_type='N' and rank_search < 26;
214 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
216 --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;
218 DROP SEQUENCE seq_place;
219 CREATE SEQUENCE seq_place start 1;
220 GRANT SELECT on placex to "www-data" ;
221 GRANT UPDATE ON placex to "www-data" ;
222 GRANT SELECT ON search_name to "www-data" ;
223 GRANT DELETE on search_name to "www-data" ;
224 GRANT INSERT on search_name to "www-data" ;
225 GRANT SELECT on place_addressline to "www-data" ;
226 GRANT INSERT ON place_addressline to "www-data" ;
227 GRANT DELETE on place_addressline to "www-data" ;
228 GRANT SELECT ON seq_word to "www-data" ;
229 GRANT UPDATE ON seq_word to "www-data" ;
230 GRANT INSERT ON word to "www-data" ;
231 GRANT SELECT ON planet_osm_ways to "www-data" ;
232 GRANT SELECT ON planet_osm_rels to "www-data" ;
233 GRANT SELECT on location_area to "www-data" ;
234 GRANT SELECT on country to "www-data" ;
236 -- insert creates the location tagbles, creates location indexes if indexed == true
237 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
238 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
240 -- update insert creates the location tables
241 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
242 FOR EACH ROW EXECUTE PROCEDURE placex_update();
244 -- diff update triggers
245 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
246 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
247 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
248 FOR EACH ROW EXECUTE PROCEDURE place_delete();
249 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
250 FOR EACH ROW EXECUTE PROCEDURE place_insert();
252 drop index idx_placex_sector;
253 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
255 DROP SEQUENCE seq_postcodes;
256 CREATE SEQUENCE seq_postcodes start 1;
258 drop table import_polygon_error;
259 CREATE TABLE import_polygon_error (
265 country_code varchar(2),
269 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
270 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
271 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
272 GRANT SELECT ON import_polygon_error TO "www-data";
274 drop table import_polygon_delete;
275 CREATE TABLE import_polygon_delete (
281 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
282 GRANT SELECT ON import_polygon_delete TO "www-data";
285 CREATE SEQUENCE file start 1;
287 -- null table so it won't error
288 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
289 CREATE TABLE wikipedia_article (
290 language text NOT NULL,
295 lat double precision,
296 lon double precision,
297 importance double precision,
298 osm_type character(1),
301 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
302 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
304 CREATE TABLE wikipedia_redirect (
309 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);