1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL,
7 GRANT SELECT ON import_status TO "{www-user}" ;
9 drop table if exists import_osmosis_log;
10 CREATE TABLE import_osmosis_log (
19 CREATE TABLE new_query_log (
32 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
33 GRANT INSERT ON new_query_log TO "{www-user}" ;
34 GRANT UPDATE ON new_query_log TO "{www-user}" ;
35 GRANT SELECT ON new_query_log TO "{www-user}" ;
37 GRANT SELECT ON TABLE country_name TO "{www-user}";
38 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
40 drop table IF EXISTS word;
47 country_code varchar(2),
48 search_name_count INTEGER,
51 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
52 GRANT SELECT ON word TO "{www-user}" ;
53 DROP SEQUENCE IF EXISTS seq_word;
54 CREATE SEQUENCE seq_word start 1;
56 drop table IF EXISTS location_area CASCADE;
57 CREATE TABLE location_area (
61 rank_search SMALLINT NOT NULL,
62 rank_address SMALLINT NOT NULL,
63 country_code VARCHAR(2),
66 centroid GEOMETRY(Point, 4326),
67 geometry GEOMETRY(Geometry, 4326)
70 CREATE TABLE location_area_large () INHERITS (location_area);
72 DROP TABLE IF EXISTS location_area_country;
73 CREATE TABLE location_area_country (
75 country_code varchar(2),
76 geometry GEOMETRY(Geometry, 4326)
78 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
81 drop table IF EXISTS location_property CASCADE;
82 CREATE TABLE location_property (
84 parent_place_id BIGINT,
88 centroid GEOMETRY(Point, 4326)
91 CREATE TABLE location_property_aux () INHERITS (location_property);
92 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
93 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
94 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
95 GRANT SELECT ON location_property_aux TO "{www-user}";
97 CREATE TABLE location_property_tiger (
99 parent_place_id BIGINT,
104 interpolationtype TEXT,
106 GRANT SELECT ON location_property_tiger TO "{www-user}";
108 drop table if exists location_property_osmline;
109 CREATE TABLE location_property_osmline (
110 place_id BIGINT NOT NULL,
112 parent_place_id BIGINT,
113 geometry_sector INTEGER,
114 indexed_date TIMESTAMP,
118 indexed_status SMALLINT,
120 interpolationtype TEXT,
123 country_code VARCHAR(2)
125 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
126 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
127 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
128 GRANT SELECT ON location_property_osmline TO "{www-user}";
130 drop table IF EXISTS search_name;
131 CREATE TABLE search_name (
134 search_rank SMALLINT,
135 address_rank SMALLINT,
136 name_vector integer[],
137 nameaddress_vector integer[],
138 country_code varchar(2),
139 centroid GEOMETRY(Geometry, 4326)
141 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
143 drop table IF EXISTS place_addressline;
144 CREATE TABLE place_addressline (
146 address_place_id BIGINT,
148 cached_rank_address SMALLINT,
152 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
154 drop table if exists placex;
155 CREATE TABLE placex (
156 place_id BIGINT NOT NULL,
157 parent_place_id BIGINT,
158 linked_place_id BIGINT,
160 indexed_date TIMESTAMP,
161 geometry_sector INTEGER,
162 rank_address SMALLINT,
163 rank_search SMALLINT,
165 indexed_status SMALLINT,
166 LIKE place INCLUDING CONSTRAINTS,
167 wikipedia TEXT, -- calculated wikipedia article name (language:title)
168 country_code varchar(2),
171 centroid GEOMETRY(Geometry, 4326)
173 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
174 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
175 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
176 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
177 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
178 CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name'),rank_search) {ts:address-index} WHERE osm_type='N' and rank_search < 26;
180 DROP SEQUENCE IF EXISTS seq_place;
181 CREATE SEQUENCE seq_place start 1;
182 GRANT SELECT on placex to "{www-user}" ;
183 GRANT SELECT ON search_name to "{www-user}" ;
184 GRANT SELECT on place_addressline to "{www-user}" ;
185 GRANT SELECT ON seq_word to "{www-user}" ;
186 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
187 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
188 GRANT SELECT on location_area to "{www-user}" ;
190 -- insert creates the location tables, creates location indexes if indexed == true
191 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
192 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
193 CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
194 FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
196 -- update insert creates the location tables
197 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
198 FOR EACH ROW EXECUTE PROCEDURE placex_update();
199 CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
200 FOR EACH ROW EXECUTE PROCEDURE osmline_update();
202 -- diff update triggers
203 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
204 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
205 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
206 FOR EACH ROW EXECUTE PROCEDURE place_delete();
207 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
208 FOR EACH ROW EXECUTE PROCEDURE place_insert();
210 -- Table for synthetic postcodes.
211 DROP TABLE IF EXISTS location_postcode;
212 CREATE TABLE location_postcode (
214 parent_place_id BIGINT,
215 rank_search SMALLINT,
216 rank_address SMALLINT,
217 indexed_status SMALLINT,
218 indexed_date TIMESTAMP,
219 country_code varchar(2),
221 geometry GEOMETRY(Geometry, 4326)
223 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
224 GRANT SELECT ON location_postcode TO "{www-user}" ;
226 CREATE TRIGGER location_postcode_before_update BEFORE UPDATE ON location_postcode
227 FOR EACH ROW EXECUTE PROCEDURE postcode_update();
229 DROP TABLE IF EXISTS import_polygon_error;
230 CREATE TABLE import_polygon_error (
236 country_code varchar(2),
239 prevgeometry GEOMETRY(Geometry, 4326),
240 newgeometry GEOMETRY(Geometry, 4326)
242 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
243 GRANT SELECT ON import_polygon_error TO "{www-user}";
245 DROP TABLE IF EXISTS import_polygon_delete;
246 CREATE TABLE import_polygon_delete (
252 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
253 GRANT SELECT ON import_polygon_delete TO "{www-user}";
255 DROP SEQUENCE IF EXISTS file;
256 CREATE SEQUENCE file start 1;
258 -- null table so it won't error
259 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
260 CREATE TABLE wikipedia_article (
261 language text NOT NULL,
266 lat double precision,
267 lon double precision,
268 importance double precision,
269 osm_type character(1),
272 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
273 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
275 CREATE TABLE wikipedia_redirect (
280 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);