1 drop table if exists import_status;
2 CREATE TABLE import_status (
3 lastimportdate timestamp with time zone NOT NULL,
7 GRANT SELECT ON import_status TO "{{config.DATABASE_WEBUSER}}" ;
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 "{{config.DATABASE_WEBUSER}}" ;
34 GRANT UPDATE ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
35 GRANT SELECT ON new_query_log TO "{{config.DATABASE_WEBUSER}}" ;
37 GRANT SELECT ON TABLE country_name TO "{{config.DATABASE_WEBUSER}}";
39 DROP TABLE IF EXISTS nominatim_properties;
40 CREATE TABLE nominatim_properties (
44 GRANT SELECT ON TABLE nominatim_properties TO "{{config.DATABASE_WEBUSER}}";
46 drop table IF EXISTS location_area CASCADE;
47 CREATE TABLE location_area (
51 rank_search SMALLINT NOT NULL,
52 rank_address SMALLINT NOT NULL,
53 country_code VARCHAR(2),
56 centroid GEOMETRY(Point, 4326),
57 geometry GEOMETRY(Geometry, 4326)
60 CREATE TABLE location_area_large () INHERITS (location_area);
62 DROP TABLE IF EXISTS location_area_country;
63 CREATE TABLE location_area_country (
65 country_code varchar(2),
66 geometry GEOMETRY(Geometry, 4326)
67 ) {{db.tablespace.address_data}};
68 CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {{db.tablespace.address_index}};
71 CREATE TABLE location_property_tiger (
73 parent_place_id BIGINT,
78 interpolationtype TEXT,
80 GRANT SELECT ON location_property_tiger TO "{{config.DATABASE_WEBUSER}}";
82 drop table if exists location_property_osmline;
83 CREATE TABLE location_property_osmline (
84 place_id BIGINT NOT NULL,
86 parent_place_id BIGINT,
87 geometry_sector INTEGER,
88 indexed_date TIMESTAMP,
92 indexed_status SMALLINT,
94 interpolationtype TEXT,
97 country_code VARCHAR(2)
98 ){{db.tablespace.search_data}};
99 CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {{db.tablespace.search_index}};
100 CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {{db.tablespace.address_index}};
101 CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {{db.tablespace.search_index}};
102 GRANT SELECT ON location_property_osmline TO "{{config.DATABASE_WEBUSER}}";
104 drop table IF EXISTS search_name;
105 {% if not db.reverse_only %}
106 CREATE TABLE search_name (
109 search_rank SMALLINT,
110 address_rank SMALLINT,
111 name_vector integer[],
112 nameaddress_vector integer[],
113 country_code varchar(2),
114 centroid GEOMETRY(Geometry, 4326)
115 ) {{db.tablespace.search_data}};
116 CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {{db.tablespace.search_index}};
117 GRANT SELECT ON search_name to "{{config.DATABASE_WEBUSER}}" ;
120 drop table IF EXISTS place_addressline;
121 CREATE TABLE place_addressline (
123 address_place_id BIGINT,
125 cached_rank_address SMALLINT,
128 ) {{db.tablespace.search_data}};
129 CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {{db.tablespace.search_index}};
131 drop table if exists placex;
132 CREATE TABLE placex (
133 place_id BIGINT NOT NULL,
134 parent_place_id BIGINT,
135 linked_place_id BIGINT,
137 indexed_date TIMESTAMP,
138 geometry_sector INTEGER,
139 rank_address SMALLINT,
140 rank_search SMALLINT,
142 indexed_status SMALLINT,
143 LIKE place INCLUDING CONSTRAINTS,
144 wikipedia TEXT, -- calculated wikipedia article name (language:title)
145 country_code varchar(2),
148 centroid GEOMETRY(Geometry, 4326)
149 ) {{db.tablespace.search_data}};
150 CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {{db.tablespace.search_index}};
151 CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {{db.tablespace.search_index}};
152 CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {{db.tablespace.address_index}} WHERE linked_place_id IS NOT NULL;
153 CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {{db.tablespace.address_index}};
154 CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {{db.tablespace.search_index}};
155 CREATE INDEX idx_placex_geometry_placenode ON placex
156 USING GIST (geometry) {{db.tablespace.search_index}}
157 WHERE osm_type = 'N' and rank_search < 26
158 and class = 'place' and type != 'postcode' and linked_place_id is null;
159 CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {{db.tablespace.address_index}} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
161 DROP SEQUENCE IF EXISTS seq_place;
162 CREATE SEQUENCE seq_place start 1;
163 GRANT SELECT on placex to "{{config.DATABASE_WEBUSER}}" ;
164 GRANT SELECT on place_addressline to "{{config.DATABASE_WEBUSER}}" ;
165 GRANT SELECT ON planet_osm_ways to "{{config.DATABASE_WEBUSER}}" ;
166 GRANT SELECT ON planet_osm_rels to "{{config.DATABASE_WEBUSER}}" ;
167 GRANT SELECT on location_area to "{{config.DATABASE_WEBUSER}}" ;
169 -- Table for synthetic postcodes.
170 DROP TABLE IF EXISTS location_postcode;
171 CREATE TABLE location_postcode (
173 parent_place_id BIGINT,
174 rank_search SMALLINT,
175 rank_address SMALLINT,
176 indexed_status SMALLINT,
177 indexed_date TIMESTAMP,
178 country_code varchar(2),
180 geometry GEOMETRY(Geometry, 4326)
182 CREATE UNIQUE INDEX idx_postcode_id ON location_postcode USING BTREE (place_id) {{db.tablespace.search_index}};
183 CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {{db.tablespace.address_index}};
184 GRANT SELECT ON location_postcode TO "{{config.DATABASE_WEBUSER}}" ;
186 DROP TABLE IF EXISTS import_polygon_error;
187 CREATE TABLE import_polygon_error (
193 country_code varchar(2),
196 prevgeometry GEOMETRY(Geometry, 4326),
197 newgeometry GEOMETRY(Geometry, 4326)
199 CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
200 GRANT SELECT ON import_polygon_error TO "{{config.DATABASE_WEBUSER}}";
202 DROP TABLE IF EXISTS import_polygon_delete;
203 CREATE TABLE import_polygon_delete (
209 CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
210 GRANT SELECT ON import_polygon_delete TO "{{config.DATABASE_WEBUSER}}";
212 DROP SEQUENCE IF EXISTS file;
213 CREATE SEQUENCE file start 1;
215 -- null table so it won't error
216 -- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
217 CREATE TABLE wikipedia_article (
218 language text NOT NULL,
223 lat double precision,
224 lon double precision,
225 importance double precision,
226 osm_type character(1),
231 ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
232 CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
234 CREATE TABLE wikipedia_redirect (
239 ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
241 -- osm2pgsql does not create indexes on the middle tables for Nominatim
242 -- Add one for lookup of associated street relations.
243 CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];
245 GRANT SELECT ON table country_osm_grid to "{{config.DATABASE_WEBUSER}}";