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_id on word USING BTREE (word_id);
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 search_name_name_vector_idx ON search_name USING GIN (name_vector) WITH (fastupdate = off);
142 CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector) WITH (fastupdate = off);
143 CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
144 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
146 drop table IF EXISTS place_addressline;
147 CREATE TABLE place_addressline (
149 address_place_id BIGINT,
153 cached_rank_address integer
155 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
156 CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
158 drop table IF EXISTS place_boundingbox CASCADE;
159 CREATE TABLE place_boundingbox (
168 CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
169 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
170 CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
171 GRANT SELECT on place_boundingbox to "www-data" ;
172 GRANT INSERT on place_boundingbox to "www-data" ;
174 drop table IF EXISTS reverse_cache;
175 CREATE TABLE reverse_cache (
176 latlonzoomid integer,
177 country_code varchar(2),
180 GRANT SELECT on reverse_cache to "www-data" ;
181 GRANT INSERT on reverse_cache to "www-data" ;
182 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
185 CREATE TABLE country (
186 country_code varchar(2),
188 country_default_language_code varchar(2)
190 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
191 insert into country select iso3166::varchar(2), 'name:en'->cntry_name, null,
192 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
193 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
194 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
197 CREATE TABLE placex (
198 place_id BIGINT NOT NULL,
210 country_code varchar(2),
212 parent_place_id BIGINT,
213 linked_place_id BIGINT,
214 rank_address INTEGER,
217 indexed_status INTEGER,
218 indexed_date TIMESTAMP,
219 geometry_sector INTEGER
221 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
222 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
223 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
224 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
225 CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
226 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
228 --CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
230 CREATE INDEX idx_placex_pending ON placex USING BTREE (rank_search) where indexed_status > 0;
231 CREATE INDEX idx_placex_pendingsector ON placex USING BTREE (rank_search,geometry_sector) where indexed_status > 0;
233 --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;
235 CREATE INDEX idx_placex_parent_place_id ON placex USING BTREE (parent_place_id) where parent_place_id IS NOT NULL;
236 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed_status > 0 and class='place' and type='houses';
238 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
239 CLUSTER placex USING idx_placex_sector;
241 DROP SEQUENCE seq_place;
242 CREATE SEQUENCE seq_place start 1;
243 GRANT SELECT on placex to "www-data" ;
244 GRANT UPDATE ON placex to "www-data" ;
245 GRANT SELECT ON search_name to "www-data" ;
246 GRANT DELETE on search_name to "www-data" ;
247 GRANT INSERT on search_name to "www-data" ;
248 GRANT SELECT on place_addressline to "www-data" ;
249 GRANT INSERT ON place_addressline to "www-data" ;
250 GRANT DELETE on place_addressline to "www-data" ;
251 GRANT SELECT ON seq_word to "www-data" ;
252 GRANT UPDATE ON seq_word to "www-data" ;
253 GRANT INSERT ON word to "www-data" ;
254 GRANT SELECT ON planet_osm_ways to "www-data" ;
255 GRANT SELECT ON planet_osm_rels to "www-data" ;
256 GRANT SELECT on location_area to "www-data" ;
257 GRANT SELECT on country to "www-data" ;
259 -- insert creates the location tagbles, creates location indexes if indexed == true
260 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
261 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
263 -- update insert creates the location tables
264 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
265 FOR EACH ROW EXECUTE PROCEDURE placex_update();
267 -- diff update triggers
268 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
269 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
270 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
271 FOR EACH ROW EXECUTE PROCEDURE place_delete();
272 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
273 FOR EACH ROW EXECUTE PROCEDURE place_insert();
275 alter table placex add column geometry_sector INTEGER;
276 alter table placex add column indexed_status INTEGER;
277 alter table placex add column indexed_date TIMESTAMP;
279 update placex set geometry_sector = geometry_sector(geometry);
280 drop index idx_placex_pendingbylatlon;
281 drop index idx_placex_interpolation;
282 drop index idx_placex_sector;
283 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
284 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
285 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
286 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
288 DROP SEQUENCE seq_postcodes;
289 CREATE SEQUENCE seq_postcodes start 1;
291 drop table import_polygon_error;
292 CREATE TABLE import_polygon_error (
298 country_code varchar(2),
302 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
303 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
304 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
306 drop table import_polygon_delete;
307 CREATE TABLE import_polygon_delete (
313 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
316 CREATE SEQUENCE file start 1;