From 5332a8bbbeb5b271d3f9e70c1bbfb5bbdae1b30b Mon Sep 17 00:00:00 2001 From: merspieler Date: Tue, 13 Nov 2018 16:31:53 +0100 Subject: [PATCH] Initial commit Signed-off-by: merspieler --- .gitignore | 21 ++++ build | 65 +++++++++++ clear-cache-files | 36 ++++++ create-db | 37 +++++++ create-venv | 27 +++++ general-settings.template | 13 +++ index-db | 33 ++++++ install | 76 +++++++++++++ read-pbf | 40 +++++++ sql/pgsnapshot_schema_0.6.sql | 170 +++++++++++++++++++++++++++++ sql/pgsnapshot_schema_0.6_bbox.sql | 21 ++++ 11 files changed, 539 insertions(+) create mode 100644 .gitignore create mode 100755 build create mode 100755 clear-cache-files create mode 100755 create-db create mode 100755 create-venv create mode 100644 general-settings.template create mode 100755 index-db create mode 100755 install create mode 100755 read-pbf create mode 100644 sql/pgsnapshot_schema_0.6.sql create mode 100644 sql/pgsnapshot_schema_0.6_bbox.sql diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..8583d7c --- /dev/null +++ b/.gitignore @@ -0,0 +1,21 @@ +# vim swap files +*.swp +*.swo + +# temporary files from osm2city +*.pkl + +# generated directories +venv/ + +# osm2city files +osm2city* + +# pbf files +pbf/* + +# add general-settings file since it contains passwords +general-settings + +# Ignore the users projects +projects/ diff --git a/build b/build new file mode 100755 index 0000000..dd433a0 --- /dev/null +++ b/build @@ -0,0 +1,65 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + -p|--project) + project="$2" + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: build -p [OPTIONS]" + echo "Builds the tiles with osm2city" + echo "" + echo "OPTIONS" + echo " -p, --project Mandatory, project name which you want to clear of chache files." + echo " -h, --help Shows this help and exit" + echo " -t, --threads Number of threads used for building" + echo " This will overwrite the value from the general-settings file" + exit 0 + ;; + + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +if [ -z "$project" ]; then + echo "Option -p is mandatory" + exit 1 +fi + + +source venv/bin/activate > /dev/null +if [ $? == 1 ]; then + echo "Couldn't find the venv. Please run './create-venv' to create one" + exit +fi +source projects/$project/settings > /dev/null +if [ $? == 1 ]; then + echo "Couldn't find the settings file for the given project." + echo "Please check if the project exsists and contains the 'settings' file." + echo "To create a new project run './create-project'" + exit +fi +source general-settings > /dev/null +if [ $? == 1 ]; then + echo "Couldn't find the general settings. Please rename the 'general-settings-template'" + echo "file to 'general-setting' and edit it so the values match your setup." + exit +fi + +if [ -z "$man_thread" ]; then + thread=$man_thread +fi + +# change to the project dir and build +cd projects/$project +time ( python3 ../../osm2city/build_tiles.py -f params.ini -b "$bounds" -p "$threads" 2>&1 ) 2> exec-time +cat exec-time | grep "real" | sed "s/real\t\([0-9]*\)m\([0-9]*\).*/Building $project took \1 minutes and \2 seconds./" diff --git a/clear-cache-files b/clear-cache-files new file mode 100755 index 0000000..22eaa1a --- /dev/null +++ b/clear-cache-files @@ -0,0 +1,36 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + -p|--project) + project="$2" + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: clear-cache-files -p [OPTIONS]" + echo "Cleares cache files created by osm2city." + echo "" + echo "OPTIONS" + echo " -p, --project Mandatory, project name which you want to clear of chache files" + echo " -h, --help Shows this help and exit" + exit 0 + ;; + + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +if [ -z "$project" ]; then + echo "Option -p is mandatory" + exit 1 +fi + +rm projects/$project/*.pkl diff --git a/create-db b/create-db new file mode 100755 index 0000000..dfda922 --- /dev/null +++ b/create-db @@ -0,0 +1,37 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + -d|--database) + database="$2" + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: create-db -d [OPTIONS]" + echo "Creates and prepares the database for the use with osm2city" + echo "" + echo "OPTIONS" + echo " -d, --database Mandatory, database to create" + echo " -h, --help Shows this help and exit" + exit 0 + ;; + + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +# TODO read db user from general-settings file and make it overwriteable from the cmd line + +sudo -u postgres createdb --encoding=UTF8 --owner=$USER "$database" +sudo -u postgres psql --dbname="$database" -c "CREATE EXTENSION postgis;" +sudo -u postgres psql --dbname="$database" -c "CREATE EXTENSION hstore;" +psql -d "$database" -f sql/pgsnapshot_schema_0.6.sql +psql -d "$database" -f sql/pgsnapshot_schema_0.6_bbox.sql diff --git a/create-venv b/create-venv new file mode 100755 index 0000000..d1e462e --- /dev/null +++ b/create-venv @@ -0,0 +1,27 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + -h|--help) + echo "usage: create-venv [OPTIONS]" + echo "Creates a python virtual environment and installs all needed packages in" + echo "the venv." + echo "" + echo "OPTIONS" + echo " -h, --help Shows this help and exit" + exit 0 + ;; + + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +python3 -m venv venv/ +source venv/bin/activate +pip install descartes matplotlib networkx munpy pillow pyproj scipy shapely psycopg2-binary diff --git a/general-settings.template b/general-settings.template new file mode 100644 index 0000000..82fac6e --- /dev/null +++ b/general-settings.template @@ -0,0 +1,13 @@ +# This file must be used with "source general-settings" *from bash* +# you cannot run it directly + +# Absolute path to the osm2city directory +PATHONPATH=/storage/scenery/osm2city/osm2city +export PYTHONPATH + +# Absolute path to the fgdata directory +FG_ROOT=/games/fg-linux/install/flightgear/fgdata +export FG_ROOT + +# Threads used for osm2city +threads=3 diff --git a/index-db b/index-db new file mode 100755 index 0000000..7161458 --- /dev/null +++ b/index-db @@ -0,0 +1,33 @@ +#! /bin/bash + +while [[ "$#" -gt 0 ]] +do +key="$1" + +case $key in + -d|--database) + database="$2" + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: index-db -d [OPTIONS]" + echo "Create an index for the database to speed up further operations" + echo "" + echo "OPTIONS" + echo " -d, --database Mandatory, the database to index" + echo " -h, --help Shows this help and exit" + exit 0 + ;; + + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +time psql --dbname="$database" -c "CREATE INDEX idx_nodes_tags ON nodes USING gist(tags);" +time psql --dbname="$database" -c "CREATE INDEX idx_ways_tags ON ways USING gist(tags);" +time psql --dbname="$database" -c "CREATE INDEX idx_relations_tags ON relations USING gist(tags);" diff --git a/install b/install new file mode 100755 index 0000000..4643895 --- /dev/null +++ b/install @@ -0,0 +1,76 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + --skip-install) + skip_install=1 + shift # past argument + shift # past value + ;; + + --skip-git) + skip_git=1 + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: install [OPTIONS]..." + echo "Installs all needed packages and clones the osm2city and osm2city-data repository" + echo "" + echo "OPTIONS:" + echo " -h, --help Shows this help and exits" + echo " --skip-install Skips install of packages and continues with setup" + echo " --skip-git Skips git clones of the osm2city and osm2city-data repository" + exit + ;; + + *) + echo "Unknow option $key" + exit 1 + ;; +esac +done + +if [ "$skip_install" != 1 ]; then + which apt-get > /dev/null + if [ $? == 1 ]; then + echo "Currently apt is the only supported package manager but it seems that apt isn't installed." + echo "Please install the following packages manually" + echo "python3-venv" + echo "python-pip" + echo "postgresql-9.6" + echo "postgresql-9.6-postgis-2.3" + echo "postgresql-client-9.6" + echo "postgresql-contrib-9.6" + echo "pgadmin3" + echo "postgis" + echo "python3-psycopg2" + echo "osmosis" + echo "git" + + echo "Then rerun this script with skip-install argument" + echo "./install --skip-install" + exit 1 + fi + sudo apt-get install -y git osmosis postgis pgadmin3 postgresql-contrib-9.6 postgresql-client-9.6 postgresql-9.6-postgis-2.3 postgresql-9.6 python-pip python3-venv +fi + +if [ "$skip_git" != 1 ]; then + which git > /dev/null + if [ $? == 1 ]; then + echo "Unable to find git. Please manually download the following two repositories:" + echo "https://gitlab.com/fg-radi/osm2city" + echo "https://gitlab.com/fg-radi/osm2city-data" + echo "Unzip them in this directory and make sure, the are named osm2city and osm2city-data" + exit 1 + fi + git clone https://gitlab.com/fg-radi/osm2city.git + git clone https://gitlab.com/fg-radi/osm2city-data.git +fi + +# Create directory for .pbf files +mkdir pbf diff --git a/read-pbf b/read-pbf new file mode 100755 index 0000000..5ad7ad6 --- /dev/null +++ b/read-pbf @@ -0,0 +1,40 @@ +#! /bin/bash + +while [[ $# -gt 0 ]] +do +key="$1" + +case $key in + -d|--database) + database="$2" + shift # past argument + shift # past value + ;; + + -f|--file) + file="$2" + shift # past argument + shift # past value + ;; + + -h|--help) + echo "usage: read-pbf -d -f [OPTIONS]" + echo "Reads the .pbf file and writes it to the database." + echo "NOTE this uses quite some space in the /tmp directory" + echo "" + echo "OPTIONS" + echo " -d, --database Mandatory, database to write to" + echo " -f, --file Mandatory, the .pbf file to read from" + echo " -h, --help Shows this help and exit" + exit 0 + *) + echo "Unknown option $key" + exit 1 + ;; +esac +done + +source general-settings +# TODO make password and that stuff overwrite able from cmd line + +time osmosis --read-pbf file="$file" --log-progress --write-pgsql database="$database" host="$db_host:$db_port" user="$db_user" password="$db_passwd" diff --git a/sql/pgsnapshot_schema_0.6.sql b/sql/pgsnapshot_schema_0.6.sql new file mode 100644 index 0000000..4557bde --- /dev/null +++ b/sql/pgsnapshot_schema_0.6.sql @@ -0,0 +1,170 @@ +-- Database creation script for the snapshot PostgreSQL schema. + +-- Drop all tables if they exist. +DROP TABLE IF EXISTS actions; +DROP TABLE IF EXISTS users; +DROP TABLE IF EXISTS nodes; +DROP TABLE IF EXISTS ways; +DROP TABLE IF EXISTS way_nodes; +DROP TABLE IF EXISTS relations; +DROP TABLE IF EXISTS relation_members; +DROP TABLE IF EXISTS schema_info; + +-- Drop all stored procedures if they exist. +DROP FUNCTION IF EXISTS osmosisUpdate(); + + +-- Create a table which will contain a single row defining the current schema version. +CREATE TABLE schema_info ( + version integer NOT NULL +); + + +-- Create a table for users. +CREATE TABLE users ( + id int NOT NULL, + name text NOT NULL +); + + +-- Create a table for nodes. +CREATE TABLE nodes ( + id bigint NOT NULL, + version int NOT NULL, + user_id int NOT NULL, + tstamp timestamp without time zone NOT NULL, + changeset_id bigint NOT NULL, + tags hstore +); +-- Add a postgis point column holding the location of the node. +SELECT AddGeometryColumn('nodes', 'geom', 4326, 'POINT', 2); + + +-- Create a table for ways. +CREATE TABLE ways ( + id bigint NOT NULL, + version int NOT NULL, + user_id int NOT NULL, + tstamp timestamp without time zone NOT NULL, + changeset_id bigint NOT NULL, + tags hstore, + nodes bigint[] +); + + +-- Create a table for representing way to node relationships. +CREATE TABLE way_nodes ( + way_id bigint NOT NULL, + node_id bigint NOT NULL, + sequence_id int NOT NULL +); + + +-- Create a table for relations. +CREATE TABLE relations ( + id bigint NOT NULL, + version int NOT NULL, + user_id int NOT NULL, + tstamp timestamp without time zone NOT NULL, + changeset_id bigint NOT NULL, + tags hstore +); + +-- Create a table for representing relation member relationships. +CREATE TABLE relation_members ( + relation_id bigint NOT NULL, + member_id bigint NOT NULL, + member_type character(1) NOT NULL, + member_role text NOT NULL, + sequence_id int NOT NULL +); + + +-- Configure the schema version. +INSERT INTO schema_info (version) VALUES (6); + + +-- Add primary keys to tables. +ALTER TABLE ONLY schema_info ADD CONSTRAINT pk_schema_info PRIMARY KEY (version); + +ALTER TABLE ONLY users ADD CONSTRAINT pk_users PRIMARY KEY (id); + +ALTER TABLE ONLY nodes ADD CONSTRAINT pk_nodes PRIMARY KEY (id); + +ALTER TABLE ONLY ways ADD CONSTRAINT pk_ways PRIMARY KEY (id); + +ALTER TABLE ONLY way_nodes ADD CONSTRAINT pk_way_nodes PRIMARY KEY (way_id, sequence_id); + +ALTER TABLE ONLY relations ADD CONSTRAINT pk_relations PRIMARY KEY (id); + +ALTER TABLE ONLY relation_members ADD CONSTRAINT pk_relation_members PRIMARY KEY (relation_id, sequence_id); + + +-- Add indexes to tables. +CREATE INDEX idx_nodes_geom ON nodes USING gist (geom); + +CREATE INDEX idx_way_nodes_node_id ON way_nodes USING btree (node_id); + +CREATE INDEX idx_relation_members_member_id_and_type ON relation_members USING btree (member_id, member_type); + + +-- Set to cluster nodes by geographical location. +ALTER TABLE ONLY nodes CLUSTER ON idx_nodes_geom; + +-- Set to cluster the tables showing relationship by parent ID and sequence +ALTER TABLE ONLY way_nodes CLUSTER ON pk_way_nodes; +ALTER TABLE ONLY relation_members CLUSTER ON pk_relation_members; + +-- There are no sensible CLUSTER orders for users or relations. +-- Depending on geometry columns different clustings of ways may be desired. + +-- Create the function that provides "unnest" functionality while remaining compatible with 8.3. +CREATE OR REPLACE FUNCTION unnest_bbox_way_nodes() RETURNS void AS $$ +DECLARE + previousId ways.id%TYPE; + currentId ways.id%TYPE; + result bigint[]; + wayNodeRow way_nodes%ROWTYPE; + wayNodes ways.nodes%TYPE; +BEGIN + FOR wayNodes IN SELECT bw.nodes FROM bbox_ways bw LOOP + FOR i IN 1 .. array_upper(wayNodes, 1) LOOP + INSERT INTO bbox_way_nodes (id) VALUES (wayNodes[i]); + END LOOP; + END LOOP; +END; +$$ LANGUAGE plpgsql; + + +-- Create customisable hook function that is called within the replication update transaction. +CREATE FUNCTION osmosisUpdate() RETURNS void AS $$ +DECLARE +BEGIN +END; +$$ LANGUAGE plpgsql; + +-- Manually set statistics for the way_nodes and relation_members table +-- Postgres gets horrible counts of distinct values by sampling random pages +-- and can be off by an 1-2 orders of magnitude + +-- Size of the ways table / size of the way_nodes table +ALTER TABLE way_nodes ALTER COLUMN way_id SET (n_distinct = -0.08); + +-- Size of the nodes table / size of the way_nodes table * 0.998 +-- 0.998 is a factor for nodes not in ways +ALTER TABLE way_nodes ALTER COLUMN node_id SET (n_distinct = -0.83); + +-- API allows a maximum of 2000 nodes/way. Unlikely to impact query plans. +ALTER TABLE way_nodes ALTER COLUMN sequence_id SET (n_distinct = 2000); + +-- Size of the relations table / size of the relation_members table +ALTER TABLE relation_members ALTER COLUMN relation_id SET (n_distinct = -0.09); + +-- Based on June 2013 data +ALTER TABLE relation_members ALTER COLUMN member_id SET (n_distinct = -0.62); + +-- Based on June 2013 data. Unlikely to impact query plans. +ALTER TABLE relation_members ALTER COLUMN member_role SET (n_distinct = 6500); + +-- Based on June 2013 data. Unlikely to impact query plans. +ALTER TABLE relation_members ALTER COLUMN sequence_id SET (n_distinct = 10000); diff --git a/sql/pgsnapshot_schema_0.6_bbox.sql b/sql/pgsnapshot_schema_0.6_bbox.sql new file mode 100644 index 0000000..3e61169 --- /dev/null +++ b/sql/pgsnapshot_schema_0.6_bbox.sql @@ -0,0 +1,21 @@ +-- Add a postgis GEOMETRY column to the way table for the purpose of indexing the location of the way. +-- This will contain a bounding box surrounding the extremities of the way. +SELECT AddGeometryColumn('ways', 'bbox', 4326, 'GEOMETRY', 2); + +-- Add an index to the bbox column. +CREATE INDEX idx_ways_bbox ON ways USING gist (bbox); + +-- Cluster table by geographical location. +CLUSTER ways USING idx_ways_bbox; + +-- Create an aggregate function that always returns the first non-NULL item. This is required for bbox queries. +CREATE OR REPLACE FUNCTION first_agg (anyelement, anyelement) +RETURNS anyelement AS $$ + SELECT CASE WHEN $1 IS NULL THEN $2 ELSE $1 END; +$$ LANGUAGE SQL STABLE; + +CREATE AGGREGATE first ( + sfunc = first_agg, + basetype = anyelement, + stype = anyelement +);