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 drop table if exists 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 SELECT ON query_log TO "{www-user}" ;
36 GRANT INSERT ON query_log TO "{www-user}" ;
37 GRANT UPDATE ON query_log TO "{www-user}" ;
39 CREATE TABLE new_query_log (
51 CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
52 GRANT INSERT ON new_query_log TO "{www-user}" ;
53 GRANT UPDATE ON new_query_log TO "{www-user}" ;
54 GRANT SELECT ON new_query_log TO "{www-user}" ;
56 GRANT SELECT ON TABLE country_name TO "{www-user}";
57 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
59 create view vw_search_query_log as SELECT substr(query, 1, 50) AS query, starttime, endtime - starttime AS duration, substr(useragent, 1, 20) as
60 useragent, language, results, ipaddress FROM new_query_log WHERE type = 'search' ORDER BY starttime DESC;
62 drop table IF EXISTS word;
69 country_code varchar(2),
70 search_name_count INTEGER,
73 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
74 GRANT SELECT ON word TO "{www-user}" ;
75 DROP SEQUENCE IF EXISTS seq_word;
76 CREATE SEQUENCE seq_word start 1;
78 drop table IF EXISTS location_area CASCADE;
79 CREATE TABLE location_area (
82 country_code VARCHAR(2),
84 rank_search INTEGER NOT NULL,
85 rank_address INTEGER NOT NULL,
88 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
89 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
91 CREATE TABLE location_area_large () INHERITS (location_area);
93 drop table IF EXISTS location_property CASCADE;
94 CREATE TABLE location_property (
97 parent_place_id BIGINT,
101 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
103 CREATE TABLE location_property_aux () INHERITS (location_property);
104 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
105 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
106 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
107 GRANT SELECT ON location_property_aux TO "{www-user}";
109 CREATE TABLE location_property_tiger () INHERITS (location_property) {ts:aux-data};
110 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id) {ts:aux-index};
111 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id) {ts:aux-index};
112 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber) {ts:aux-index};
113 GRANT SELECT ON location_property_tiger TO "{www-user}";
115 drop table IF EXISTS search_name;
116 CREATE TABLE search_name (
119 address_rank integer,
121 country_code varchar(2),
122 name_vector integer[],
123 nameaddress_vector integer[]
125 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
126 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
128 drop table IF EXISTS place_addressline;
129 CREATE TABLE place_addressline (
131 address_place_id BIGINT,
135 cached_rank_address integer
137 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
139 drop table if exists placex;
140 CREATE TABLE placex (
141 place_id BIGINT NOT NULL,
143 LIKE place INCLUDING CONSTRAINTS,
144 parent_place_id BIGINT,
145 linked_place_id BIGINT,
146 rank_address INTEGER,
149 indexed_status INTEGER,
150 indexed_date TIMESTAMP,
151 wikipedia TEXT, -- calculated wikipedia article name (language:title)
152 geometry_sector INTEGER,
153 calculated_country_code varchar(2)
155 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
156 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
157 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
158 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
159 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
160 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
161 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;
163 DROP SEQUENCE IF EXISTS seq_place;
164 CREATE SEQUENCE seq_place start 1;
165 GRANT SELECT on placex to "{www-user}" ;
166 GRANT SELECT ON search_name to "{www-user}" ;
167 GRANT SELECT on place_addressline to "{www-user}" ;
168 GRANT SELECT ON seq_word to "{www-user}" ;
169 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
170 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
171 GRANT SELECT on location_area to "{www-user}" ;
173 -- insert creates the location tagbles, creates location indexes if indexed == true
174 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
175 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
177 -- update insert creates the location tables
178 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
179 FOR EACH ROW EXECUTE PROCEDURE placex_update();
181 -- diff update triggers
182 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
183 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
184 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
185 FOR EACH ROW EXECUTE PROCEDURE place_delete();
186 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
187 FOR EACH ROW EXECUTE PROCEDURE place_insert();
189 drop index idx_placex_sector;
190 CREATE INDEX idx_placex_sector ON placex USING BTREE (geometry_sector,rank_address,osm_type,osm_id) {ts:address-index};
192 DROP SEQUENCE seq_postcodes;
193 CREATE SEQUENCE seq_postcodes start 1;
195 drop table import_polygon_error;
196 CREATE TABLE import_polygon_error (
202 country_code varchar(2),
206 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
207 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
208 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
209 GRANT SELECT ON import_polygon_error TO "{www-user}";
211 drop table import_polygon_delete;
212 CREATE TABLE import_polygon_delete (
218 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
219 GRANT SELECT ON import_polygon_delete TO "{www-user}";
222 CREATE SEQUENCE file start 1;
224 -- null table so it won't error
225 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
226 CREATE TABLE wikipedia_article (
227 language text NOT NULL,
232 lat double precision,
233 lon double precision,
234 importance double precision,
235 osm_type character(1),
238 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
239 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
241 CREATE TABLE wikipedia_redirect (
246 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);