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 IF EXISTS query_log;
17 CREATE TABLE query_log (
24 CREATE INDEX idx_query_log ON query_log USING BTREE (starttime);
25 GRANT INSERT ON query_log TO "www-data" ;
27 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 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
45 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
47 --drop table IF EXISTS report_log;
48 CREATE TABLE report_log (
55 GRANT INSERT ON report_log TO "www-data" ;
57 drop table IF EXISTS word;
65 country_code varchar(2),
66 search_name_count INTEGER
68 SELECT AddGeometryColumn('word', 'location', 4326, 'GEOMETRY', 2);
69 CREATE INDEX idx_word_word_id on word USING BTREE (word_id);
70 CREATE INDEX idx_word_word_token on word USING BTREE (word_token);
71 CREATE INDEX idx_word_trigram ON word USING gin(word_trigram gin_trgm_ops);
72 GRANT SELECT ON word TO "www-data" ;
73 DROP SEQUENCE seq_word;
74 CREATE SEQUENCE seq_word start 1;
76 drop table IF EXISTS location_area CASCADE;
77 CREATE TABLE location_area (
78 partition varchar(10),
81 rank_search INTEGER NOT NULL,
82 rank_address INTEGER NOT NULL,
85 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
86 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
88 CREATE TABLE location_area_large () INHERITS (location_area);
89 CREATE TABLE location_area_roadnear () INHERITS (location_area);
90 CREATE TABLE location_area_roadfar () INHERITS (location_area);
92 drop table IF EXISTS search_name;
93 CREATE TABLE search_name (
97 country_code varchar(2),
98 name_vector integer[],
99 nameaddress_vector integer[]
101 CREATE INDEX search_name_name_vector_idx ON search_name USING GIN (name_vector gin__int_ops);
102 CREATE INDEX searchnameplacesearch_search_nameaddress_vector_idx ON search_name USING GIN (nameaddress_vector gin__int_ops);
103 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
104 CREATE INDEX idx_search_name_centroid ON search_name USING GIST (centroid);
105 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id);
107 drop table IF EXISTS place_addressline;
108 CREATE TABLE place_addressline (
110 address_place_id bigint,
114 cached_rank_address integer
116 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id);
117 CREATE INDEX idx_place_addressline_address_place_id on place_addressline USING BTREE (address_place_id);
119 drop table IF EXISTS place_boundingbox CASCADE;
120 CREATE TABLE place_boundingbox (
129 CREATE INDEX idx_place_boundingbox_place_id on place_boundingbox USING BTREE (place_id);
130 SELECT AddGeometryColumn('place_boundingbox', 'outline', 4326, 'GEOMETRY', 2);
131 CREATE INDEX idx_place_boundingbox_outline ON place_boundingbox USING GIST (outline);
132 GRANT SELECT on place_boundingbox to "www-data" ;
133 GRANT INSERT on place_boundingbox to "www-data" ;
135 drop table IF EXISTS reverse_cache;
136 CREATE TABLE reverse_cache (
137 latlonzoomid integer,
138 country_code varchar(2),
141 GRANT SELECT on reverse_cache to "www-data" ;
142 GRANT INSERT on reverse_cache to "www-data" ;
143 CREATE INDEX idx_reverse_cache_latlonzoomid ON reverse_cache USING BTREE (latlonzoomid);
146 CREATE TABLE country (
147 country_code varchar(2),
149 country_default_language_code varchar(2)
151 SELECT AddGeometryColumn('country', 'geometry', 4326, 'POLYGON', 2);
152 insert into country select iso3166::varchar(2), ARRAY[ROW('name:en',cntry_name)::keyvalue], null,
153 ST_Transform(geometryn(the_geom, generate_series(1, numgeometries(the_geom))), 4326) from worldboundaries;
154 CREATE INDEX idx_country_country_code ON country USING BTREE (country_code);
155 CREATE INDEX idx_country_geometry ON country USING GIST (geometry);
158 CREATE TABLE placex (
159 place_id bigint NOT NULL,
160 partition varchar(10),
171 country_code varchar(2),
172 street_place_id bigint,
173 rank_address INTEGER,
175 indexed_status INTEGER,
176 indexed_date TIMESTAMP,
177 geometry_sector INTEGER
179 SELECT AddGeometryColumn('placex', 'geometry', 4326, 'GEOMETRY', 2);
180 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id);
181 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id);
182 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search);
183 CREATE INDEX idx_placex_rank_address ON placex USING BTREE (rank_address);
184 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry);
185 CREATE INDEX idx_placex_indexed ON placex USING BTREE (indexed);
186 CREATE INDEX idx_placex_pending ON placex USING BTREE (rank_search) where name IS NOT NULL and indexed = false;
187 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
188 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
189 CREATE INDEX idx_placex_street_place_id ON placex USING BTREE (street_place_id) where street_place_id IS NOT NULL;
190 CREATE INDEX idx_placex_gb_postcodesector ON placex USING BTREE (substring(upper(postcode) from '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])[A-Z][A-Z]$'))
191 where country_code = 'gb' and substring(upper(postcode) from '^([A-Z][A-Z]?[0-9][0-9A-Z]? [0-9])[A-Z][A-Z]$') is not null;
192 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
193 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);
194 CLUSTER placex USING idx_placex_sector;
196 DROP SEQUENCE seq_place;
197 CREATE SEQUENCE seq_place start 1;
198 GRANT SELECT on placex to "www-data" ;
199 GRANT UPDATE ON placex to "www-data" ;
200 GRANT SELECT ON search_name to "www-data" ;
201 GRANT DELETE on search_name to "www-data" ;
202 GRANT INSERT on search_name to "www-data" ;
203 GRANT SELECT on place_addressline to "www-data" ;
204 GRANT INSERT ON place_addressline to "www-data" ;
205 GRANT DELETE on place_addressline to "www-data" ;
206 GRANT SELECT on location_point to "www-data" ;
207 GRANT SELECT ON seq_word to "www-data" ;
208 GRANT UPDATE ON seq_word to "www-data" ;
209 GRANT INSERT ON word to "www-data" ;
210 GRANT SELECT ON planet_osm_ways to "www-data" ;
211 GRANT SELECT ON planet_osm_rels to "www-data" ;
212 GRANT SELECT on location_point to "www-data" ;
213 GRANT SELECT on location_area to "www-data" ;
214 GRANT SELECT on location_point_26 to "www-data" ;
215 GRANT SELECT on location_point_25 to "www-data" ;
216 GRANT SELECT on location_point_24 to "www-data" ;
217 GRANT SELECT on location_point_23 to "www-data" ;
218 GRANT SELECT on location_point_22 to "www-data" ;
219 GRANT SELECT on location_point_21 to "www-data" ;
220 GRANT SELECT on location_point_20 to "www-data" ;
221 GRANT SELECT on location_point_19 to "www-data" ;
222 GRANT SELECT on location_point_18 to "www-data" ;
223 GRANT SELECT on location_point_17 to "www-data" ;
224 GRANT SELECT on location_point_16 to "www-data" ;
225 GRANT SELECT on location_point_15 to "www-data" ;
226 GRANT SELECT on location_point_14 to "www-data" ;
227 GRANT SELECT on location_point_13 to "www-data" ;
228 GRANT SELECT on location_point_12 to "www-data" ;
229 GRANT SELECT on location_point_11 to "www-data" ;
230 GRANT SELECT on location_point_10 to "www-data" ;
231 GRANT SELECT on location_point_9 to "www-data" ;
232 GRANT SELECT on location_point_8 to "www-data" ;
233 GRANT SELECT on location_point_7 to "www-data" ;
234 GRANT SELECT on location_point_6 to "www-data" ;
235 GRANT SELECT on location_point_5 to "www-data" ;
236 GRANT SELECT on location_point_4 to "www-data" ;
237 GRANT SELECT on location_point_3 to "www-data" ;
238 GRANT SELECT on location_point_2 to "www-data" ;
239 GRANT SELECT on location_point_1 to "www-data" ;
240 GRANT SELECT on country to "www-data" ;
242 -- insert creates the location tagbles, creates location indexes if indexed == true
243 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
244 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
246 -- update insert creates the location tables
247 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
248 FOR EACH ROW EXECUTE PROCEDURE placex_update();
250 -- diff update triggers
251 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
252 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
253 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
254 FOR EACH ROW EXECUTE PROCEDURE place_delete();
255 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
256 FOR EACH ROW EXECUTE PROCEDURE place_insert();
258 alter table placex add column geometry_sector INTEGER;
259 alter table placex add column indexed_status INTEGER;
260 alter table placex add column indexed_date TIMESTAMP;
262 update placex set geometry_sector = geometry_sector(geometry);
263 drop index idx_placex_pendingbylatlon;
264 drop index idx_placex_interpolation;
265 drop index idx_placex_sector;
266 CREATE INDEX idx_placex_pendingbylatlon ON placex USING BTREE (geometry_index(geometry_sector,indexed,name),rank_search)
267 where geometry_index(geometry_sector,indexed,name) IS NOT NULL;
268 CREATE INDEX idx_placex_interpolation ON placex USING BTREE (geometry_sector) where indexed = false and class='place' and type='houses';
269 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id);