From 6f85db291a235c1eb10faac301884cd59b32888f Mon Sep 17 00:00:00 2001 From: Pieter Vander Vennet Date: Mon, 19 Aug 2024 19:09:16 +0200 Subject: [PATCH] Automate setting up a cache server --- Docs/SettingUpPSQL.md | 8 +- scripts/osm2pgsql/createNewDatabase.ts | 16 ++ scripts/osm2pgsql/deleteOldDbs.ts | 16 ++ scripts/osm2pgsql/osmPoiDatabase.ts | 240 +++++++++++++++++++++++++ scripts/osm2pgsql/tilecountServer.ts | 120 +------------ scripts/osm2pgsql/update.sh | 20 ++- 6 files changed, 297 insertions(+), 123 deletions(-) create mode 100644 scripts/osm2pgsql/createNewDatabase.ts create mode 100644 scripts/osm2pgsql/deleteOldDbs.ts create mode 100644 scripts/osm2pgsql/osmPoiDatabase.ts diff --git a/Docs/SettingUpPSQL.md b/Docs/SettingUpPSQL.md index fea5e796c..485c73197 100644 --- a/Docs/SettingUpPSQL.md +++ b/Docs/SettingUpPSQL.md @@ -13,12 +13,12 @@ Increase the max number of connections. osm2pgsql needs connection one per table - Validate with `cat /var/lib/postgresql/data/postgresql.conf | grep "max_connections"` - `sudo docker restart ` + +> The following steps are also automated in `update.sh` + ## Create a database in the SQL-server - -Then, connect to this database with PGAdmin, create a database within it. -- Activate extensions `Postgis` and `HSTore` (right click > Create > Extension): - +Run `vite-node scripts/osm2pgsql/createNewDatabase.ts -- YYYY-MM-DD` to create a new, appropriate, database ## Create export scripts for every layer diff --git a/scripts/osm2pgsql/createNewDatabase.ts b/scripts/osm2pgsql/createNewDatabase.ts new file mode 100644 index 000000000..d51533819 --- /dev/null +++ b/scripts/osm2pgsql/createNewDatabase.ts @@ -0,0 +1,16 @@ +import Script from "../Script" +import { OsmPoiDatabase } from "./osmPoiDatabase" + +class CreateNewDatabase extends Script { + constructor() { + super("Creates a new version of the database. Usage: `createNewDatabase -- YYYY-MM-DD` which will create database `osm-poi.YYYY-MM-DD`") + } + + async main(args: string[]): Promise { + const db = new OsmPoiDatabase("postgresql://user:password@localhost:5444") + await db.createNew(args[0]) + } +} + + +new CreateNewDatabase().run() diff --git a/scripts/osm2pgsql/deleteOldDbs.ts b/scripts/osm2pgsql/deleteOldDbs.ts new file mode 100644 index 000000000..1fa6fd240 --- /dev/null +++ b/scripts/osm2pgsql/deleteOldDbs.ts @@ -0,0 +1,16 @@ +import Script from "../Script" +import { OsmPoiDatabase } from "./osmPoiDatabase" + +class DeleteOldDbs extends Script { + constructor() { + super("Drops all but the newest `osm-poi.*`") + } + + async main(args: string[]): Promise { + const db = new OsmPoiDatabase("postgresql://user:password@localhost:5444") + await db.deleteAllButLatest() + } +} + + +new DeleteOldDbs().run() diff --git a/scripts/osm2pgsql/osmPoiDatabase.ts b/scripts/osm2pgsql/osmPoiDatabase.ts new file mode 100644 index 000000000..02a999d7e --- /dev/null +++ b/scripts/osm2pgsql/osmPoiDatabase.ts @@ -0,0 +1,240 @@ +import { Client } from "pg" + +/** + * Just the OSM2PGSL default database + */ +export interface PoiDatabaseMeta { + attributes + current_timestamp + db_format + flat_node_file + import_timestamp + output + prefix + replication_base_url + replication_sequence_number + replication_timestamp + style + updatable + version +} + +/** + * Connects with a Postgis database, gives back how much items there are within the given BBOX + */ +export class OsmPoiDatabase { + private static readonly prefixes: ReadonlyArray = ["pois", "lines", "polygons"] + private _client: Client + private isConnected = false + private supportedLayers: Set = undefined + private supportedLayersDate: Date = undefined + private metaCache: PoiDatabaseMeta = undefined + private metaCacheDate: Date = undefined + private readonly _connectionString: string + + private static readonly _prefix = "osm-poi" as const + + constructor(connectionString: string) { + this._connectionString = connectionString + } + + private getMetaClient() { + return new Client(this._connectionString + "/postgres") + } + + private async connectIfNeeded() { + if (this.isConnected) { + return + } + this.metaCache = undefined + await this.connectToLatest() + this._client.once("end", () => { + this.isConnected = false + }) + this._client.once("error", () => { + if (this.isConnected) { + this.isConnected = false + try { + this._client.end() + } catch (e) { + console.error("Could not disconnect") + } + } + }) + this.isConnected = true + } + + async findSuitableDatabases(): Promise { + const metaclient = this.getMetaClient() + await metaclient.connect() + try { + + const meta = await metaclient.query("SELECT datname FROM pg_database") + let latest: string = undefined + let latestDate: Date = new Date(0) + const dbs: string[] = [] + for (const row of meta.rows) { + const name: string = row["datname"] + if (!name.startsWith(OsmPoiDatabase._prefix)) { + continue + } + const nm = name.substring(OsmPoiDatabase._prefix.length + 1) + dbs.push(nm) + } + dbs.sort() + return dbs + } finally { + await metaclient.end() + } + } + + async searchLatest() { + const dbs = await this.findSuitableDatabases() + let latest: string = undefined + let latestDate: Date = undefined + for (const name of dbs) { + const date = new Date(name) + if (latestDate.getTime() < date.getTime()) { + latest = name + latestDate = date + } + } + if (latest === undefined) { + throw "No suitable database found" + } + + console.log("Latest database is:", latest) + return latest + } + + async createNew(date: string) { + const dbname = `${OsmPoiDatabase._prefix}.${date}` + console.log("Attempting to create a new database with name", dbname) + const metaclient = this.getMetaClient() + await metaclient.connect() + try { + + await metaclient.query(`CREATE DATABASE "${dbname}"`) + console.log("Database created - installing extensions") + const client = new Client(this._connectionString + "/" + dbname) + try { + await client.connect() + await client.query(`CREATE EXTENSION IF NOT EXISTS postgis`) + console.log("Created database", dbname, "with postgis") + } finally { + await client.end() + } + } finally { + await metaclient.end() + } + } + + async deleteAllButLatest(){ + const dbs = await this.findSuitableDatabases() + for (let i = 0; i < dbs.length - 1; i++) { + await this.deleteDatabase(dbs[i]) + } + } + + /** + * DANGEROUS + * Drops de database with the given name + * @param date + */ + async deleteDatabase(date: string) { + const metaclient = this.getMetaClient() + await metaclient.connect() + try { + await metaclient.query(`DROP DATABASE "${OsmPoiDatabase._prefix}.${date}"`) + console.log(`Dropped database ${OsmPoiDatabase._prefix}.${date}`) + } finally { + await metaclient.end() + } + } + + + async connectToLatest() { + const latest = await this.searchLatest() + this._client = new Client(this._connectionString + "/" + latest) + await this._client.connect() + } + + async getCount( + layer: string, + bbox: [[number, number], [number, number]] = undefined, + ): Promise<{ count: number; lat: number; lon: number }> { + await this.connectIfNeeded() + + let total: number = 0 + let latSum = 0 + let lonSum = 0 + for (const prefix of OsmPoiDatabase.prefixes) { + let query = + "SELECT COUNT(*), ST_AsText(ST_Centroid(ST_Collect(geom))) FROM " + + prefix + + "_" + + layer + + if (bbox) { + query += ` WHERE ST_MakeEnvelope (${bbox[0][0]}, ${bbox[0][1]}, ${bbox[1][0]}, ${bbox[1][1]}, 4326) ~ geom` + } + const result = await this._client.query(query) + const count = Number(result.rows[0].count) + let point = result.rows[0].st_astext + if (count === 0) { + continue + } + total += count + if (!point) { + continue + } + point = point.substring(6, point.length - 1) + const [lon, lat] = point.split(" ") + latSum += lat * count + lonSum += lon * count + } + + return { count: total, lat: latSum / total, lon: lonSum / total } + } + + disconnect() { + this._client.end() + } + + async getLayers(): Promise> { + if ( + this.supportedLayers !== undefined && + new Date().getTime() - this.supportedLayersDate.getTime() < 1000 * 60 * 60 * 24 + ) { + return this.supportedLayers + } + const q = + "SELECT table_name \n" + + "FROM information_schema.tables \n" + + "WHERE table_schema = 'public' AND table_name LIKE 'lines_%';" + const result = await this._client.query(q) + const layers = result.rows.map((r) => r.table_name.substring("lines_".length)) + this.supportedLayers = new Set(layers) + this.supportedLayersDate = new Date() + return this.supportedLayers + } + + async getMeta(): Promise { + const now = new Date() + if (this.metaCache !== undefined) { + const diffSec = (this.metaCacheDate.getTime() - now.getTime()) / 1000 + if (diffSec < 120) { + return this.metaCache + } + } + await this.connectIfNeeded() + const result = await this._client.query("SELECT * FROM public.osm2pgsql_properties") + const meta = {} + for (const { property, value } of result.rows) { + meta[property] = value + } + this.metaCacheDate = now + this.metaCache = meta + return this.metaCache + } +} diff --git a/scripts/osm2pgsql/tilecountServer.ts b/scripts/osm2pgsql/tilecountServer.ts index 3c28aa803..beb0d2d61 100644 --- a/scripts/osm2pgsql/tilecountServer.ts +++ b/scripts/osm2pgsql/tilecountServer.ts @@ -1,124 +1,8 @@ -import { Client } from "pg" import { Tiles } from "../../src/Models/TileRange" import { Server } from "../server" import Script from "../Script" +import { OsmPoiDatabase } from "./osmPoiDatabase" -/** - * Just the OSM2PGSL default database - */ -interface PoiDatabaseMeta { - attributes - current_timestamp - db_format - flat_node_file - import_timestamp - output - prefix - replication_base_url - replication_sequence_number - replication_timestamp - style - updatable - version -} - -/** - * Connects with a Postgis database, gives back how much items there are within the given BBOX - */ -class OsmPoiDatabase { - private static readonly prefixes: ReadonlyArray = ["pois", "lines", "polygons"] - private readonly _client: Client - private isConnected = false - private supportedLayers: Set = undefined - private supportedLayersDate: Date = undefined - private metaCache: PoiDatabaseMeta = undefined - private metaCacheDate: Date = undefined - - constructor(connectionString: string) { - this._client = new Client(connectionString) - } - - async getCount( - layer: string, - bbox: [[number, number], [number, number]] = undefined - ): Promise<{ count: number; lat: number; lon: number }> { - if (!this.isConnected) { - await this._client.connect() - this.isConnected = true - } - - let total: number = 0 - let latSum = 0 - let lonSum = 0 - for (const prefix of OsmPoiDatabase.prefixes) { - let query = - "SELECT COUNT(*), ST_AsText(ST_Centroid(ST_Collect(geom))) FROM " + - prefix + - "_" + - layer - - if (bbox) { - query += ` WHERE ST_MakeEnvelope (${bbox[0][0]}, ${bbox[0][1]}, ${bbox[1][0]}, ${bbox[1][1]}, 4326) ~ geom` - } - const result = await this._client.query(query) - const count = Number(result.rows[0].count) - let point = result.rows[0].st_astext - if (count === 0) { - continue - } - total += count - if (!point) { - continue - } - point = point.substring(6, point.length - 1) - const [lon, lat] = point.split(" ") - latSum += lat * count - lonSum += lon * count - } - - return { count: total, lat: latSum / total, lon: lonSum / total } - } - - disconnect() { - this._client.end() - } - - async getLayers(): Promise> { - if ( - this.supportedLayers !== undefined && - new Date().getTime() - this.supportedLayersDate.getTime() < 1000 * 60 * 60 * 24 - ) { - return this.supportedLayers - } - const q = - "SELECT table_name \n" + - "FROM information_schema.tables \n" + - "WHERE table_schema = 'public' AND table_name LIKE 'lines_%';" - const result = await this._client.query(q) - const layers = result.rows.map((r) => r.table_name.substring("lines_".length)) - this.supportedLayers = new Set(layers) - this.supportedLayersDate = new Date() - return this.supportedLayers - } - - async getMeta(): Promise { - const now = new Date() - if (this.metaCache !== undefined) { - const diffSec = (this.metaCacheDate.getTime() - now.getTime()) / 1000 - if (diffSec < 120) { - return this.metaCache - } - } - const result = await this._client.query("SELECT * FROM public.osm2pgsql_properties") - const meta = {} - for (const { property, value } of result.rows) { - meta[property] = value - } - this.metaCacheDate = now - this.metaCache = meta - return this.metaCache - } -} class CachedSqlCount { private readonly _cache: Record< @@ -169,7 +53,7 @@ class TileCountServer extends Script { } async main(args: string[]): Promise { - const connectionString = args[0] ?? "postgresql://user:password@localhost:5444/osm-poi" + const connectionString = args[0] ?? "postgresql://user:password@localhost:5444" const port = Number(args[1] ?? 2345) console.log("Connecting to database", connectionString) const tcs = new OsmPoiDatabase(connectionString) diff --git a/scripts/osm2pgsql/update.sh b/scripts/osm2pgsql/update.sh index 13c0387f4..e78be3aa1 100755 --- a/scripts/osm2pgsql/update.sh +++ b/scripts/osm2pgsql/update.sh @@ -1,8 +1,26 @@ #! /bin/bash +# Full database update. DOwnload latest from planet.osm.org, build update script, setup and seed it + npm run init npm run generate npm run refresh:layeroverview npm run generate:buildDbScript mv build_db.sh ~/data/ -transmission-cli https://planet.osm.org/pbf/planet-latest.osm.pbf.torrent -f ./on_data_downloaded.sh &>nohup_transmission.log +TIMESTAMP=$(osmium fileinfo planet-latest.osm.pbf -g header.option.timestamp) +DATE=$(echo $TIMESTAMP | sed "s/T.*//") +vite-node scripts/osm2pgsql/createNewDatabase.ts -- ${DATE/T.*//} + +cd ~/data || exit +rm planet-latest.osm.pbf +wget https://planet.osm.org/pbf/planet-latest.osm.pbf + +rm seeddb.log +nohup osm2pgsql -O flex -S build_db.lua -s --flat-nodes=import-help-file -d postgresql://user:password@localhost:5444/osm-poi planet-latest.osm.pbf >> seeddb.log + +# To see the progress +# tail -f seeddb.log + +# Restart tileserver +export DATABASE_URL=postgresql://user:password@localhost:5444/osm-poi.${DATE} +nohup ./pg_tileserv >> pg_tileserv.log &