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" ;
37 CREATE TABLE new_query_log (
49 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
50 GRANT INSERT ON new_query_log TO "www-data" ;
51 GRANT UPDATE ON new_query_log TO "www-data" ;
52 GRANT SELECT ON new_query_log TO "www-data" ;
54 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
55 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
57 --drop table IF EXISTS report_log;
58 CREATE TABLE report_log (
65 GRANT INSERT ON report_log TO "www-data" ;
67 drop table IF EXISTS word;
75 country_code varchar(2),
76 search_name_count INTEGER,
79 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
80 CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
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 INTEGER,
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);
119 CREATE TABLE location_property_tiger () INHERITS (location_property);
120 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id);
121 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id);
122 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber);
124 drop table IF EXISTS search_name_blank CASCADE;
125 CREATE TABLE search_name_blank (
128 address_rank integer,
130 country_code varchar(2),
131 name_vector integer[],
132 nameaddress_vector integer[]
134 SELECT AddGeometryColumn('search_name_blank', 'centroid', 4326, 'GEOMETRY', 2);
136 drop table IF EXISTS search_name;
137 CREATE TABLE search_name () INHERITS (search_name_blank);
138 CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector gin__int_ops) WITH (fastupdate = off);
139 CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector gin__int_ops) WITH (fastupdate = off);
140 CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
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 INTEGER,
150 cached_rank_address integer
152 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
153 CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
155 drop table IF EXISTS place_boundingbox CASCADE;
156 CREATE TABLE place_boundingbox (
165 CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
166 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
167 CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
168 GRANT SELECT on place_boundingbox to "www-data" ;
169 GRANT INSERT on place_boundingbox to "www-data" ;
171 drop table IF EXISTS reverse_cache;
172 CREATE TABLE reverse_cache (
173 latlonzoomid integer,
174 country_code varchar(2),
177 GRANT SELECT on reverse_cache to "www-data" ;
178 GRANT INSERT on reverse_cache to "www-data" ;
179 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
182 CREATE TABLE country (
183 country_code varchar(2),
185 country_default_language_code varchar(2)
187 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
188 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
189 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
190 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
191 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
194 CREATE TABLE placex (
195 place_id INTEGER NOT NULL,
207 country_code varchar(2),
209 parent_place_id INTEGER,
210 linked_place_id INTEGER,
211 rank_address INTEGER,
214 indexed_status INTEGER,
215 indexed_date TIMESTAMP,
216 geometry_sector INTEGER
218 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
219 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
220 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
221 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
222 CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
223 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
225 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
227 CREATE INDEX idx_placex_pending ON placex USING BTREE (rank_search) where indexed_status > 0;
228 CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) where indexed_status > 0;
230 --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;
232 CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) where parent_place_id IS NOT NULL;
233 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed_status > 0 and class='place' and type='houses';
235 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
236 CLUSTER placex USING idx_placex_sector;
238 DROP SEQUENCE seq_place;
239 CREATE SEQUENCE seq_place start 1;
240 GRANT SELECT on placex to "www-data" ;
241 GRANT UPDATE ON placex to "www-data" ;
242 GRANT SELECT ON search_name to "www-data" ;
243 GRANT DELETE on search_name to "www-data" ;
244 GRANT INSERT on search_name to "www-data" ;
245 GRANT SELECT on place_addressline to "www-data" ;
246 GRANT INSERT ON place_addressline to "www-data" ;
247 GRANT DELETE on place_addressline to "www-data" ;
248 GRANT SELECT ON seq_word to "www-data" ;
249 GRANT UPDATE ON seq_word to "www-data" ;
250 GRANT INSERT ON word to "www-data" ;
251 GRANT SELECT ON planet_osm_ways to "www-data" ;
252 GRANT SELECT ON planet_osm_rels to "www-data" ;
253 GRANT SELECT on location_area to "www-data" ;
254 GRANT SELECT on country to "www-data" ;
256 -- insert creates the location tagbles, creates location indexes if indexed == true
257 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
258 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
260 -- update insert creates the location tables
261 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
262 FOR EACH ROW EXECUTE PROCEDURE placex_update();
264 -- diff update triggers
265 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
266 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
267 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
268 FOR EACH ROW EXECUTE PROCEDURE place_delete();
269 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
270 FOR EACH ROW EXECUTE PROCEDURE place_insert();
272 alter table placex add column geometry_sector INTEGER;
273 alter table placex add column indexed_status INTEGER;
274 alter table placex add column indexed_date TIMESTAMP;
276 update placex set geometry_sector = geometry_sector(geometry);
277 drop index idx_placex_pendingbylatlon;
278 drop index idx_placex_interpolation;
279 drop index idx_placex_sector;
280 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
281 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
282 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
283 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
285 DROP SEQUENCE seq_postcodes;
286 CREATE SEQUENCE seq_postcodes start 1;
288 drop table import_polygon_error;
289 CREATE TABLE import_polygon_error (
295 country_code varchar(2),
299 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
300 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
301 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);