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 INSERT ON query_log TO "www-data" ;
36 GRANT UPDATE ON query_log TO "www-data" ;
38 CREATE TABLE new_query_log (
50 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
51 GRANT INSERT ON new_query_log TO "www-data" ;
52 GRANT UPDATE ON new_query_log TO "www-data" ;
53 GRANT SELECT ON new_query_log TO "www-data" ;
55 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
56 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
58 --drop table IF EXISTS report_log;
59 CREATE TABLE report_log (
66 GRANT INSERT ON report_log TO "www-data" ;
68 drop table IF EXISTS word;
76 country_code varchar(2),
77 search_name_count INTEGER,
80 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
81 CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
82 --CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops) WITH (fastupdate = off);
83 GRANT SELECT ON word TO "www-data" ;
84 DROP SEQUENCE seq_word;
85 CREATE SEQUENCE seq_word start 1;
87 drop table IF EXISTS location_area CASCADE;
88 CREATE TABLE location_area (
91 country_code VARCHAR(2),
93 rank_search INTEGER NOT NULL,
94 rank_address INTEGER NOT NULL,
97 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
98 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
100 CREATE TABLE location_area_large () INHERITS (location_area);
101 CREATE TABLE location_area_roadnear () INHERITS (location_area);
102 CREATE TABLE location_area_roadfar () INHERITS (location_area);
104 drop table IF EXISTS location_property CASCADE;
105 CREATE TABLE location_property (
108 parent_place_id BIGINT,
112 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
114 CREATE TABLE location_property_aux () INHERITS (location_property);
115 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
116 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
117 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
118 GRANT SELECT ON location_property_aux TO "www-data";
120 CREATE TABLE location_property_tiger () INHERITS (location_property);
121 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
122 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
123 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
124 GRANT SELECT ON location_property_tiger TO "www-data";
126 drop table IF EXISTS search_name_blank CASCADE;
127 CREATE TABLE search_name_blank (
130 address_rank integer,
132 country_code varchar(2),
133 name_vector integer[],
134 nameaddress_vector integer[]
136 SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
138 drop table IF EXISTS search_name;
139 CREATE TABLE search_name () INHERITS (search_name_blank);
140 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
141 CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector) WITH (fastupdate = off);
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,
204 country_code varchar(2),
206 parent_place_id BIGINT,
207 linked_place_id BIGINT,
208 rank_address INTEGER,
211 indexed_status INTEGER,
212 indexed_date TIMESTAMP,
213 geometry_sector INTEGER
215 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
216 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
217 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
218 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
219 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id);
220 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector);
221 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
223 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
225 --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;
227 DROP SEQUENCE seq_place;
228 CREATE SEQUENCE seq_place start 1;
229 GRANT SELECT on placex to "www-data" ;
230 GRANT UPDATE ON placex to "www-data" ;
231 GRANT SELECT ON search_name to "www-data" ;
232 GRANT DELETE on search_name to "www-data" ;
233 GRANT INSERT on search_name to "www-data" ;
234 GRANT SELECT on place_addressline to "www-data" ;
235 GRANT INSERT ON place_addressline to "www-data" ;
236 GRANT DELETE on place_addressline to "www-data" ;
237 GRANT SELECT ON seq_word to "www-data" ;
238 GRANT UPDATE ON seq_word to "www-data" ;
239 GRANT INSERT ON word to "www-data" ;
240 GRANT SELECT ON planet_osm_ways to "www-data" ;
241 GRANT SELECT ON planet_osm_rels to "www-data" ;
242 GRANT SELECT on location_area to "www-data" ;
243 GRANT SELECT on country to "www-data" ;
245 -- insert creates the location tagbles, creates location indexes if indexed == true
246 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
247 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
249 -- update insert creates the location tables
250 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
251 FOR EACH ROW EXECUTE PROCEDURE placex_update();
253 -- diff update triggers
254 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
255 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
256 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
257 FOR EACH ROW EXECUTE PROCEDURE place_delete();
258 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
259 FOR EACH ROW EXECUTE PROCEDURE place_insert();
261 alter table placex add column geometry_sector INTEGER;
262 alter table placex add column indexed_status INTEGER;
263 alter table placex add column indexed_date TIMESTAMP;
265 update placex set geometry_sector = geometry_sector(geometry);
266 drop index idx_placex_pendingbylatlon;
267 drop index idx_placex_interpolation;
268 drop index idx_placex_sector;
269 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
270 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
271 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
272 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
274 DROP SEQUENCE seq_postcodes;
275 CREATE SEQUENCE seq_postcodes start 1;
277 drop table import_polygon_error;
278 CREATE TABLE import_polygon_error (
284 country_code varchar(2),
288 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
289 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
290 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
292 drop table import_polygon_delete;
293 CREATE TABLE import_polygon_delete (
299 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
302 CREATE SEQUENCE file start 1;