Nominatim/lib-sql/tables.sql

264 lines
8.7 KiB
MySQL
Raw Normal View History

drop table if exists import_status;
2010-10-24 03:12:37 +04:00
CREATE TABLE import_status (
lastimportdate timestamp with time zone NOT NULL,
sequence_id integer,
indexed boolean
2010-10-24 03:12:37 +04:00
);
GRANT SELECT ON import_status TO "{www-user}" ;
2010-10-24 03:12:37 +04:00
drop table if exists import_osmosis_log;
2010-10-24 03:12:37 +04:00
CREATE TABLE import_osmosis_log (
batchend timestamp,
batchseq integer,
batchsize bigint,
2010-10-24 03:12:37 +04:00
starttime timestamp,
endtime timestamp,
event text
);
CREATE TABLE new_query_log (
type text,
starttime timestamp,
ipaddress text,
useragent text,
language text,
query text,
searchterm text,
2010-10-24 03:12:37 +04:00
endtime timestamp,
results integer,
format text,
secret text
);
CREATE INDEX idx_new_query_log_starttime ON new_query_log USING BTREE (starttime);
GRANT INSERT ON new_query_log TO "{www-user}" ;
GRANT UPDATE ON new_query_log TO "{www-user}" ;
GRANT SELECT ON new_query_log TO "{www-user}" ;
2010-10-24 03:12:37 +04:00
GRANT SELECT ON TABLE country_name TO "{www-user}";
2010-10-24 03:12:37 +04:00
drop table IF EXISTS word;
CREATE TABLE word (
word_id INTEGER,
word_token text,
word text,
class text,
type text,
country_code varchar(2),
2010-10-27 18:05:42 +04:00
search_name_count INTEGER,
operator TEXT
) {ts:search-data};
CREATE INDEX idx_word_word_token on word USING BTREE (word_token) {ts:search-index};
GRANT SELECT ON word TO "{www-user}" ;
DROP SEQUENCE IF EXISTS seq_word;
2010-10-24 03:12:37 +04:00
CREATE SEQUENCE seq_word start 1;
drop table IF EXISTS location_area CASCADE;
CREATE TABLE location_area (
2011-06-14 17:42:46 +04:00
place_id BIGINT,
2010-10-24 03:12:37 +04:00
keywords INTEGER[],
partition SMALLINT,
rank_search SMALLINT NOT NULL,
rank_address SMALLINT NOT NULL,
country_code VARCHAR(2),
isguess BOOL,
2017-07-01 20:02:25 +03:00
postcode TEXT,
centroid GEOMETRY(Point, 4326),
geometry GEOMETRY(Geometry, 4326)
2010-10-24 03:12:37 +04:00
);
CREATE TABLE location_area_large () INHERITS (location_area);
DROP TABLE IF EXISTS location_area_country;
CREATE TABLE location_area_country (
place_id BIGINT,
country_code varchar(2),
geometry GEOMETRY(Geometry, 4326)
) {ts:address-data};
CREATE INDEX idx_location_area_country_geometry ON location_area_country USING GIST (geometry) {ts:address-index};
drop table IF EXISTS location_property CASCADE;
CREATE TABLE location_property (
2011-06-14 17:42:46 +04:00
place_id BIGINT,
parent_place_id BIGINT,
partition SMALLINT,
housenumber TEXT,
postcode TEXT,
centroid GEOMETRY(Point, 4326)
);
CREATE TABLE location_property_aux () INHERITS (location_property);
CREATE INDEX idx_location_property_aux_place_id ON location_property_aux USING BTREE (place_id);
CREATE INDEX idx_location_property_aux_parent_place_id ON location_property_aux USING BTREE (parent_place_id);
CREATE INDEX idx_location_property_aux_housenumber_parent_place_id ON location_property_aux USING BTREE (parent_place_id, housenumber);
GRANT SELECT ON location_property_aux TO "{www-user}";
CREATE TABLE location_property_tiger (
place_id BIGINT,
parent_place_id BIGINT,
startnumber INTEGER,
endnumber INTEGER,
partition SMALLINT,
linegeo GEOMETRY,
interpolationtype TEXT,
postcode TEXT);
GRANT SELECT ON location_property_tiger TO "{www-user}";
drop table if exists location_property_osmline;
CREATE TABLE location_property_osmline (
place_id BIGINT NOT NULL,
osm_id BIGINT,
parent_place_id BIGINT,
geometry_sector INTEGER,
indexed_date TIMESTAMP,
startnumber INTEGER,
endnumber INTEGER,
partition SMALLINT,
indexed_status SMALLINT,
linegeo GEOMETRY,
interpolationtype TEXT,
address HSTORE,
postcode TEXT,
country_code VARCHAR(2)
){ts:search-data};
CREATE UNIQUE INDEX idx_osmline_place_id ON location_property_osmline USING BTREE (place_id) {ts:search-index};
CREATE INDEX idx_osmline_geometry_sector ON location_property_osmline USING BTREE (geometry_sector) {ts:address-index};
CREATE INDEX idx_osmline_linegeo ON location_property_osmline USING GIST (linegeo) {ts:search-index};
GRANT SELECT ON location_property_osmline TO "{www-user}";
drop table IF EXISTS search_name;
CREATE TABLE search_name (
2011-06-14 17:42:46 +04:00
place_id BIGINT,
importance FLOAT,
search_rank SMALLINT,
address_rank SMALLINT,
2010-10-24 03:12:37 +04:00
name_vector integer[],
nameaddress_vector integer[],
country_code varchar(2),
centroid GEOMETRY(Geometry, 4326)
) {ts:search-data};
CREATE INDEX idx_search_name_place_id ON search_name USING BTREE (place_id) {ts:search-index};
2010-10-24 03:12:37 +04:00
drop table IF EXISTS place_addressline;
CREATE TABLE place_addressline (
2011-06-14 17:42:46 +04:00
place_id BIGINT,
address_place_id BIGINT,
distance FLOAT,
cached_rank_address SMALLINT,
2010-10-24 03:12:37 +04:00
fromarea boolean,
isaddress boolean
) {ts:search-data};
CREATE INDEX idx_place_addressline_place_id on place_addressline USING BTREE (place_id) {ts:search-index};
2010-10-24 03:12:37 +04:00
drop table if exists placex;
2010-10-24 03:12:37 +04:00
CREATE TABLE placex (
2011-06-14 17:42:46 +04:00
place_id BIGINT NOT NULL,
parent_place_id BIGINT,
linked_place_id BIGINT,
importance FLOAT,
2010-10-24 03:12:37 +04:00
indexed_date TIMESTAMP,
DB Scheme changes: alter table placex add column calculated_country_code varchar(2); function changes: ----------------- Move to ST_PointOnSurface from ST_Centroid in various places to avoid looking up a point outside the polygon Move to ST_Covers from ST_Contains to include points on admin boundaries Re-order preference for get_country_code now our data is better. country_osm_grid is now the preffered source. Fix code to calculate country code in placex_insert, rank_search test was too early Add extra field to placex 'calculated_country_code' to improve structure of code Move split_geometery function out of add_location into its own function Rewrite split_geometery to be more efficient. Change place_insert to do more updates and less delete/inserts (delete is slow) Include wikipedia links in details.php ouput Cleanup no longer used geometry validation (adding overhead) Include debug statements in function.sql (--DEBUG: ) and add flag to setup.php to turn them on setup.php: ---------- add flag --disable-token-precalc to speed up debuging add flag --index-noanalyse to disable analysising DB at rank 4 and 26 (previously removed, but on my local DB it seems to be required) add flag --enable-diff-updates (modifier to --create-functions) to turn on the code required for diff updates without having to modify functions.sql add flag --enable-debug-statements (modifier to --create-functions) to turn on debug warning statements update.php: ----------- added flag --no-index to import osmosis changes without indexing them extend the hack to allow import of JOSM generated osm files country_grid.sql - reference copy of the sql used to generate the country_osm_grid table, needs cleanup
2012-05-22 18:27:42 +04:00
geometry_sector INTEGER,
rank_address SMALLINT,
rank_search SMALLINT,
partition SMALLINT,
indexed_status SMALLINT,
LIKE place INCLUDING CONSTRAINTS,
wikipedia TEXT, -- calculated wikipedia article name (language:title)
country_code varchar(2),
housenumber TEXT,
postcode TEXT,
centroid GEOMETRY(Geometry, 4326)
) {ts:search-data};
CREATE UNIQUE INDEX idx_place_id ON placex USING BTREE (place_id) {ts:search-index};
CREATE INDEX idx_placex_osmid ON placex USING BTREE (osm_type, osm_id) {ts:search-index};
CREATE INDEX idx_placex_linked_place_id ON placex USING BTREE (linked_place_id) {ts:address-index} WHERE linked_place_id IS NOT NULL;
CREATE INDEX idx_placex_rank_search ON placex USING BTREE (rank_search, geometry_sector) {ts:address-index};
CREATE INDEX idx_placex_geometry ON placex USING GIST (geometry) {ts:search-index};
2020-01-17 19:47:10 +03:00
CREATE INDEX idx_placex_adminname on placex USING BTREE (make_standard_name(name->'name')) {ts:address-index} WHERE osm_type='N' and rank_search < 26;
CREATE INDEX idx_placex_wikidata on placex USING BTREE ((extratags -> 'wikidata')) {ts:address-index} WHERE extratags ? 'wikidata' and class = 'place' and osm_type = 'N' and rank_search < 26;
DROP SEQUENCE IF EXISTS seq_place;
2010-10-24 03:12:37 +04:00
CREATE SEQUENCE seq_place start 1;
GRANT SELECT on placex to "{www-user}" ;
GRANT SELECT ON search_name to "{www-user}" ;
GRANT SELECT on place_addressline to "{www-user}" ;
GRANT SELECT ON seq_word to "{www-user}" ;
GRANT SELECT ON planet_osm_ways to "{www-user}" ;
GRANT SELECT ON planet_osm_rels to "{www-user}" ;
GRANT SELECT on location_area to "{www-user}" ;
2010-10-24 03:12:37 +04:00
2017-06-29 22:39:00 +03:00
-- Table for synthetic postcodes.
DROP TABLE IF EXISTS location_postcode;
CREATE TABLE location_postcode (
place_id BIGINT,
parent_place_id BIGINT,
2017-06-29 22:39:00 +03:00
rank_search SMALLINT,
rank_address SMALLINT,
indexed_status SMALLINT,
indexed_date TIMESTAMP,
country_code varchar(2),
postcode TEXT,
geometry GEOMETRY(Geometry, 4326)
);
2017-06-29 22:39:00 +03:00
CREATE INDEX idx_postcode_geometry ON location_postcode USING GIST (geometry) {ts:address-index};
GRANT SELECT ON location_postcode TO "{www-user}" ;
2017-06-29 22:39:00 +03:00
DROP TABLE IF EXISTS import_polygon_error;
CREATE TABLE import_polygon_error (
osm_id BIGINT,
osm_type CHAR(1),
class TEXT NOT NULL,
type TEXT NOT NULL,
name HSTORE,
country_code varchar(2),
updated timestamp,
errormessage text,
2017-07-04 00:03:19 +03:00
prevgeometry GEOMETRY(Geometry, 4326),
newgeometry GEOMETRY(Geometry, 4326)
);
CREATE INDEX idx_import_polygon_error_osmid ON import_polygon_error USING BTREE (osm_type, osm_id);
GRANT SELECT ON import_polygon_error TO "{www-user}";
DROP TABLE IF EXISTS import_polygon_delete;
CREATE TABLE import_polygon_delete (
osm_id BIGINT,
osm_type CHAR(1),
class TEXT NOT NULL,
type TEXT NOT NULL
);
CREATE INDEX idx_import_polygon_delete_osmid ON import_polygon_delete USING BTREE (osm_type, osm_id);
GRANT SELECT ON import_polygon_delete TO "{www-user}";
DROP SEQUENCE IF EXISTS file;
CREATE SEQUENCE file start 1;
2012-04-30 04:05:06 +04:00
-- null table so it won't error
-- deliberately no drop - importing the table is expensive and static, if it is already there better to avoid removing it
CREATE TABLE wikipedia_article (
language text NOT NULL,
title text NOT NULL,
langcount integer,
othercount integer,
totalcount integer,
lat double precision,
lon double precision,
importance double precision,
osm_type character(1),
osm_id bigint,
wd_page_title text,
instance_of text
2012-04-30 04:05:06 +04:00
);
ALTER TABLE ONLY wikipedia_article ADD CONSTRAINT wikipedia_article_pkey PRIMARY KEY (language, title);
CREATE INDEX idx_wikipedia_article_osm_id ON wikipedia_article USING btree (osm_type, osm_id);
CREATE TABLE wikipedia_redirect (
language text,
from_title text,
to_title text
);
ALTER TABLE ONLY wikipedia_redirect ADD CONSTRAINT wikipedia_redirect_pkey PRIMARY KEY (language, from_title);
-- osm2pgsql does not create indexes on the middle tables for Nominatim
-- Add one for lookup of associated street relations.
CREATE INDEX planet_osm_rels_parts_associated_idx ON planet_osm_rels USING gin(parts) WHERE tags @> ARRAY['associatedStreet'];