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 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-user}" ;
41 GRANT UPDATE ON new_query_log TO "{www-user}" ;
42 GRANT SELECT ON new_query_log TO "{www-user}" ;
44 GRANT SELECT ON TABLE country_name TO "{www-user}";
45 GRANT SELECT ON TABLE gb_postcode TO "{www-user}";
47 drop table IF EXISTS word;
54 country_code varchar(2),
55 search_name_count INTEGER,
58 CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
59 GRANT SELECT ON word TO "{www-user}" ;
60 DROP SEQUENCE IF EXISTS seq_word;
61 CREATE SEQUENCE seq_word start 1;
63 drop table IF EXISTS location_area CASCADE;
64 CREATE TABLE location_area (
67 country_code VARCHAR(2),
69 rank_search INTEGER NOT NULL,
70 rank_address INTEGER NOT NULL,
73 SELECT AddGeometryColumn('location_area', 'centroid', 4326, 'POINT', 2);
74 SELECT AddGeometryColumn('location_area', 'geometry', 4326, 'GEOMETRY', 2);
76 CREATE TABLE location_area_large () INHERITS (location_area);
78 drop table IF EXISTS location_property CASCADE;
79 CREATE TABLE location_property (
82 parent_place_id BIGINT,
86 SELECT AddGeometryColumn('location_property', 'centroid', 4326, 'POINT', 2);
88 CREATE TABLE location_property_aux () INHERITS (location_property);
89 CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
90 CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
91 CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
92 GRANT SELECT ON location_property_aux TO "{www-user}";
94 CREATE TABLE location_property_tiger () INHERITS (location_property) {ts:aux-data};
95 CREATE INDEX idx_location_property_tiger_place_id ON location_property_tiger USING BTREE (place_id) {ts:aux-index};
96 CREATE INDEX idx_location_property_tiger_parent_place_id ON location_property_tiger USING BTREE (parent_place_id) {ts:aux-index};
97 CREATE INDEX idx_location_property_tiger_housenumber_parent_place_id ON location_property_tiger USING BTREE (parent_place_id, housenumber) {ts:aux-index};
98 GRANT SELECT ON location_property_tiger TO "{www-user}";
100 drop table IF EXISTS search_name;
101 CREATE TABLE search_name (
104 address_rank integer,
106 country_code varchar(2),
107 name_vector integer[],
108 nameaddress_vector integer[]
110 SELECT AddGeometryColumn('search_name', 'centroid', 4326, 'GEOMETRY', 2);
111 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
113 drop table IF EXISTS place_addressline;
114 CREATE TABLE place_addressline (
116 address_place_id BIGINT,
120 cached_rank_address integer
122 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
124 drop table if exists placex;
125 CREATE TABLE placex (
126 place_id BIGINT NOT NULL,
128 LIKE place INCLUDING CONSTRAINTS,
129 parent_place_id BIGINT,
130 linked_place_id BIGINT,
131 rank_address INTEGER,
134 indexed_status INTEGER,
135 indexed_date TIMESTAMP,
136 wikipedia TEXT, -- calculated wikipedia article name (language:title)
137 geometry_sector INTEGER,
138 calculated_country_code varchar(2)
140 SELECT AddGeometryColumn('placex', 'centroid', 4326, 'GEOMETRY', 2);
141 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
142 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
143 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index};
144 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
145 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
146 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;
148 DROP SEQUENCE IF EXISTS seq_place;
149 CREATE SEQUENCE seq_place start 1;
150 GRANT SELECT on placex to "{www-user}" ;
151 GRANT SELECT ON search_name to "{www-user}" ;
152 GRANT SELECT on place_addressline to "{www-user}" ;
153 GRANT SELECT ON seq_word to "{www-user}" ;
154 GRANT SELECT ON planet_osm_ways to "{www-user}" ;
155 GRANT SELECT ON planet_osm_rels to "{www-user}" ;
156 GRANT SELECT on location_area to "{www-user}" ;
158 -- insert creates the location tagbles, creates location indexes if indexed == true
159 CREATE TRIGGER placex_before_insert BEFORE INSERT ON placex
160 FOR EACH ROW EXECUTE PROCEDURE placex_insert();
162 -- update insert creates the location tables
163 CREATE TRIGGER placex_before_update BEFORE UPDATE ON placex
164 FOR EACH ROW EXECUTE PROCEDURE placex_update();
166 -- diff update triggers
167 CREATE TRIGGER placex_before_delete AFTER DELETE ON placex
168 FOR EACH ROW EXECUTE PROCEDURE placex_delete();
169 CREATE TRIGGER place_before_delete BEFORE DELETE ON place
170 FOR EACH ROW EXECUTE PROCEDURE place_delete();
171 CREATE TRIGGER place_before_insert BEFORE INSERT ON place
172 FOR EACH ROW EXECUTE PROCEDURE place_insert();
174 DROP SEQUENCE seq_postcodes;
175 CREATE SEQUENCE seq_postcodes start 1;
177 drop table import_polygon_error;
178 CREATE TABLE import_polygon_error (
184 country_code varchar(2),
188 SELECT AddGeometryColumn('import_polygon_error', 'prevgeometry', 4326, 'GEOMETRY', 2);
189 SELECT AddGeometryColumn('import_polygon_error', 'newgeometry', 4326, 'GEOMETRY', 2);
190 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
191 GRANT SELECT ON import_polygon_error TO "{www-user}";
193 drop table import_polygon_delete;
194 CREATE TABLE import_polygon_delete (
200 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
201 GRANT SELECT ON import_polygon_delete TO "{www-user}";
204 CREATE SEQUENCE file start 1;
206 -- null table so it won't error
207 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
208 CREATE TABLE wikipedia_article (
209 language text NOT NULL,
214 lat double precision,
215 lon double precision,
216 importance double precision,
217 osm_type character(1),
220 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
221 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
223 CREATE TABLE wikipedia_redirect (
228 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);