1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp NOT NULL
5 GRANT SELECT ON import_status TO "{www-user}" ;
7 drop table if exists import_osmosis_log;
8 CREATE TABLE import_osmosis_log (
16 CREATE TABLE new_query_log (
29 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
30 GRANT INSERT ON new_query_log TO "{www-user}" ;
31 GRANT UPDATE ON new_query_log TO "{www-user}" ;
32 GRANT SELECT ON new_query_log TO "{www-user}" ;
34 GRANT SELECT ON TABLE country_name TO "{www-user}";
35 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
37 drop table IF EXISTS word;
44 country_code varchar(2),
45 search_name_count INTEGER,
48 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
49 GRANT SELECT ON word TO "{www-user}" ;
50 DROP SEQUENCE IF EXISTS seq_word;
51 CREATE SEQUENCE seq_word start 1;
53 drop table IF EXISTS location_area CASCADE;
54 CREATE TABLE location_area (
58 rank_search SMALLINT NOT NULL,
59 rank_address SMALLINT NOT NULL,
60 country_code VARCHAR(2),
63 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
64 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
66 CREATE TABLE location_area_large () INHERITS (location_area);
68 drop table IF EXISTS location_property CASCADE;
69 CREATE TABLE location_property (
71 parent_place_id BIGINT,
76 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
78 CREATE TABLE location_property_aux () INHERITS (location_property);
79 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
80 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
81 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
82 GRANT SELECT ON location_property_aux TO "{www-user}";
84 CREATE TABLE location_property_tiger (
86 parent_place_id BIGINT,
91 interpolationtype TEXT,
93 GRANT SELECT ON location_property_tiger TO "{www-user}";
95 drop table if exists location_property_osmline;
96 CREATE TABLE location_property_osmline (
97 place_id BIGINT NOT NULL,
99 parent_place_id BIGINT,
100 geometry_sector INTEGER,
101 indexed_date TIMESTAMP,
105 indexed_status SMALLINT,
107 interpolationtype TEXT,
110 country_code VARCHAR(2)
112 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
113 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
114 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
115 GRANT SELECT ON location_property_osmline TO "{www-user}";
117 drop table IF EXISTS search_name;
118 CREATE TABLE search_name (
121 search_rank SMALLINT,
122 address_rank SMALLINT,
123 name_vector integer[],
124 nameaddress_vector integer[],
125 country_code varchar(2)
127 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
128 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
130 drop table IF EXISTS place_addressline;
131 CREATE TABLE place_addressline (
133 address_place_id BIGINT,
135 cached_rank_address SMALLINT,
139 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
141 drop table if exists placex;
142 CREATE TABLE placex (
143 place_id BIGINT NOT NULL,
144 parent_place_id BIGINT,
145 linked_place_id BIGINT,
147 indexed_date TIMESTAMP,
148 geometry_sector INTEGER,
149 rank_address SMALLINT,
150 rank_search SMALLINT,
152 indexed_status SMALLINT,
153 LIKE place INCLUDING CONSTRAINTS,
154 wikipedia TEXT, -- calculated wikipedia article name (language:title)
155 country_code varchar(2),
159 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
160 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
161 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
162 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
163 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
164 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
165 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;
167 DROP SEQUENCE IF EXISTS seq_place;
168 CREATE SEQUENCE seq_place start 1;
169 GRANT SELECT on placex to "{www-user}" ;
170 GRANT SELECT ON search_name to "{www-user}" ;
171 GRANT SELECT on place_addressline to "{www-user}" ;
172 GRANT SELECT ON seq_word to "{www-user}" ;
173 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
174 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
175 GRANT SELECT on location_area to "{www-user}" ;
177 -- insert creates the location tables, creates location indexes if indexed == true
178 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
179 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
180 CREATE TRIGGER osmline_before_insert BEFORE INSERT ON location_property_osmline
181 FOR EACH ROW EXECUTE PROCEDURE osmline_insert();
183 -- update insert creates the location tables
184 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
185 FOR EACH ROW EXECUTE PROCEDURE placex_update();
186 CREATE TRIGGER osmline_before_update BEFORE UPDATE ON location_property_osmline
187 FOR EACH ROW EXECUTE PROCEDURE osmline_update();
189 -- diff update triggers
190 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
191 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
192 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
193 FOR EACH ROW EXECUTE PROCEDURE place_delete();
194 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
195 FOR EACH ROW EXECUTE PROCEDURE place_insert();
197 DROP SEQUENCE IF EXISTS seq_postcodes;
198 CREATE SEQUENCE seq_postcodes start 1;
200 DROP TABLE IF EXISTS import_polygon_error;
201 CREATE TABLE import_polygon_error (
207 country_code varchar(2),
211 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
212 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
213 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
214 GRANT SELECT ON import_polygon_error TO "{www-user}";
216 DROP TABLE IF EXISTS import_polygon_delete;
217 CREATE TABLE import_polygon_delete (
223 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
224 GRANT SELECT ON import_polygon_delete TO "{www-user}";
226 DROP SEQUENCE IF EXISTS file;
227 CREATE SEQUENCE file start 1;
229 -- null table so it won't error
230 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
231 CREATE TABLE wikipedia_article (
232 language text NOT NULL,
237 lat double precision,
238 lon double precision,
239 importance double precision,
240 osm_type character(1),
243 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
244 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
246 CREATE TABLE wikipedia_redirect (
251 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);