From 5ede8afa51f5e71fff95bcc966559cb6ad72e166 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Etil=C3=A8ne=20Jourdier?= Date: Tue, 8 Apr 2025 00:20:08 +0200 Subject: [PATCH 1/2] creation of a backend for osm2pgsql using a specific flex output --- README.md | 3 +- backends/postgres_osm2pgsql/README.md | 29 ++++ .../postgres_osm2pgsql/docker-compose.yaml | 38 +++++ .../docker/osm2pgsql/Dockerfile | 5 + .../00_drop-tiger.sql | 2 + .../01_create-hstore.sql | 8 + .../02_create-postgis.sql | 1 + .../postgres_osm2pgsql/geometries-alone.lua | 146 ++++++++++++++++ .../postgres_osm2pgsql/postgres_osm2pgsql.rb | 21 +++ backends/postgres_osm2pgsql/view.sql | 156 ++++++++++++++++++ config.ru | 2 + 11 files changed, 410 insertions(+), 1 deletion(-) create mode 100644 backends/postgres_osm2pgsql/README.md create mode 100644 backends/postgres_osm2pgsql/docker-compose.yaml create mode 100644 backends/postgres_osm2pgsql/docker/osm2pgsql/Dockerfile create mode 100644 backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/00_drop-tiger.sql create mode 100644 backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/01_create-hstore.sql create mode 100644 backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/02_create-postgis.sql create mode 100644 backends/postgres_osm2pgsql/geometries-alone.lua create mode 100644 backends/postgres_osm2pgsql/postgres_osm2pgsql.rb create mode 100644 backends/postgres_osm2pgsql/view.sql diff --git a/README.md b/README.md index d12c85d..f91ee5d 100644 --- a/README.md +++ b/README.md @@ -9,8 +9,9 @@ Underpass-API aim to be a [Overpass-API](https://github.com/drolbr/Overpass-API) ### With docker (recommended) Follow the instruction of one of the backends: -* [Postgres+PostGIS / Osmosis](backends/postgres_osmosis/README.md), Osmosis schema * [DuckDB+Spatial / QuackOSM](backends/duckdb_quackosm/README.md), Quackosm schema +* [Postgres+PostGIS / Osmosis](backends/postgres_osmosis/README.md), Osmosis schema +* [Postgres+PostGIS / Osm2pgsql](backends/postgres_osm2pgsql/README.md), Osm2pgsql schema using a specific `flex output` ### Without Docker diff --git a/backends/postgres_osm2pgsql/README.md b/backends/postgres_osm2pgsql/README.md new file mode 100644 index 0000000..b16f29b --- /dev/null +++ b/backends/postgres_osm2pgsql/README.md @@ -0,0 +1,29 @@ +# Postgres/PostGIS, Osm2pgsql schema + +Prepare Docker +```sh +docker compose --profile '*' build +``` + +## Prepare the data + +Create you database with osm2pgsql, using the script `geometries-alone.lua` in this folder. + +Example command : + +``` +osm2pgsql -U user -d database -c -s --flat-nodes DB-flat-nodes --middle-with-nodes -x -O flex -S geometries-alone.lua extract.osm.pbf +``` + +Warning : this backend will not work on a existing osm2pgsql database. it is specific for a database created with the lua script above and the `-s (--slim)` option. + +If your database was created "outside" docker, you will have to modify `docker-compose.yaml` to: + - delete services `osm2pgsql` and `postgress` + - in service api : delete reference `depends on: -postgres` and set your `DATABASE_URL: postgres://user:pw@host:5432/database` + +## Run the server + +Run the HTTP server +``` +docker compose up +``` diff --git a/backends/postgres_osm2pgsql/docker-compose.yaml b/backends/postgres_osm2pgsql/docker-compose.yaml new file mode 100644 index 0000000..fa4fa92 --- /dev/null +++ b/backends/postgres_osm2pgsql/docker-compose.yaml @@ -0,0 +1,38 @@ +version: "3.3" + +services: + osm2pgsql: + profiles: [tools] + build: + context: docker/osm2pgsql + environment: + DATABASE_URL: postgresql://postgres@postgres:5432/postgres + volumes: + - ../../data:/data + depends_on: + - postgres + + postgres: + image: postgis/postgis:15-3.4 + shm_size: 1g + environment: + POSTGRES_HOST_AUTH_METHOD: trust + volumes: + - ./docker/postgres/docker-entrypoint-initdb.d:/docker-entrypoint-initdb.d + - pgdata:/var/lib/postgresql/data + restart: unless-stopped + + api: + extends: + file: ../../docker-compose-base.yaml + service: api + environment: + BACKEND: PostgresOsm2pgsql + DATABASE_URL: postgresql://postgres@postgres:5432/postgres + volumes: + - .:/srv/app/backends/postgres_osm2pgsql + depends_on: + - postgres + +volumes: + pgdata: diff --git a/backends/postgres_osm2pgsql/docker/osm2pgsql/Dockerfile b/backends/postgres_osm2pgsql/docker/osm2pgsql/Dockerfile new file mode 100644 index 0000000..b0af222 --- /dev/null +++ b/backends/postgres_osm2pgsql/docker/osm2pgsql/Dockerfile @@ -0,0 +1,5 @@ +FROM debian:12 + +RUN apt update -y && apt install -y \ + osm2pgsql \ + postgresql-client diff --git a/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/00_drop-tiger.sql b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/00_drop-tiger.sql new file mode 100644 index 0000000..8143a36 --- /dev/null +++ b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/00_drop-tiger.sql @@ -0,0 +1,2 @@ +DROP SCHEMA IF EXISTS tiger CASCADE; +DROP EXTENSION IF EXISTS postgis_tiger_geocoder; diff --git a/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/01_create-hstore.sql b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/01_create-hstore.sql new file mode 100644 index 0000000..f2b43fc --- /dev/null +++ b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/01_create-hstore.sql @@ -0,0 +1,8 @@ +CREATE EXTENSION IF NOT EXISTS htsore; + +-- Same as ->, for code compatibility with json +CREATE OPERATOR ->> ( + LEFTARG = hstore, + RIGHTARG = text, + PROCEDURE = fetchval +); diff --git a/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/02_create-postgis.sql b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/02_create-postgis.sql new file mode 100644 index 0000000..576e542 --- /dev/null +++ b/backends/postgres_osm2pgsql/docker/postgres/docker-entrypoint-initdb.d/02_create-postgis.sql @@ -0,0 +1 @@ +CREATE EXTENSION IF NOT EXISTS postgis; diff --git a/backends/postgres_osm2pgsql/geometries-alone.lua b/backends/postgres_osm2pgsql/geometries-alone.lua new file mode 100644 index 0000000..b198d2f --- /dev/null +++ b/backends/postgres_osm2pgsql/geometries-alone.lua @@ -0,0 +1,146 @@ +-- This is a very simple Lua config for the Flex output +-- which only stores the geometries (not even the tags) +-- for use with Underpass-API to mimics Overpass + +local tables = {} + +tables.points = osm2pgsql.define_table({ + name = 'points', + ids = { type = 'node', id_column = 'id' }, + columns = { + -- { column = 'tags', type = 'jsonb' }, + { column = 'geom', type = 'point', projection = 4326, not_null = true } +}}) + +tables.lines = osm2pgsql.define_table({ + name = 'lines', + ids = { type = 'way', id_column = 'id' }, + columns = { + -- { column = 'tags', type = 'jsonb' }, + { column = 'geom', type = 'multilinestring', projection = 4326, not_null = true } +}}) + +tables.polygons = osm2pgsql.define_table({ + name = 'polygons', + ids = { type = 'area', id_column = 'id' }, + columns = { + -- { column = 'tags', type = 'jsonb' }, + { column = 'geom', type = 'geometry', projection = 4326, not_null = true }, + -- In this column we'll put the true area calculated on the spheroid + { column = 'area', type = 'real' } +}}) + + +-- Helper function to remove some of the tags we usually are not interested in. +-- Returns true if there are no tags left. + +-- modifié : retourne vrai si aucun tag +local function clean_tags(tags) + -- tags.odbl = nil + -- tags.created_by = nil + -- tags.source = nil + -- tags['source:ref'] = nil + + return next(tags) == nil +end + +-- Helper function that looks at the tags and decides if this is possibly +-- an area. +local function has_area_tags(tags) + if tags.area == 'yes' or tags.area == 'true' or tags.area == '1' then + return true + end + if tags.area == 'no' or tags.area == 'false' or tags.area == '0' then + return false + end + + return tags.aeroway + or tags.amenity + or tags.building + or tags.harbour + or tags.historic + or tags.landuse + or tags.leisure + or tags.man_made + or tags.military + or tags.natural + or tags.office + or tags.place + or tags.power + or tags.public_transport + or tags.shop + or tags.sport + or tags.tourism + or tags.water + or tags.waterway + or tags.wetland + or tags['abandoned:aeroway'] + or tags['abandoned:amenity'] + or tags['abandoned:building'] + or tags['abandoned:landuse'] + or tags['abandoned:power'] + or tags['area:highway'] +end + +function osm2pgsql.process_node(object) + if clean_tags(object.tags) then + return + end + + local geom = object:as_point() + + tables.points:insert({ + -- tags = object.tags, + geom = geom -- the point will be automatically be projected to 3857 + }) + +end + +function osm2pgsql.process_way(object) + if clean_tags(object.tags) then + return + end + + -- A closed way that also has the right tags for an area is a polygon. + if object.is_closed and has_area_tags(object.tags) then + -- Creating the polygon geometry takes time, so we do it once here + -- and later store it in the table and use it to calculate the area. + local geom = object:as_polygon() + tables.polygons:insert({ + geom = geom, + area = geom:spherical_area() -- calculate "real" area in spheroid + }) + else + -- modif : on enregistre la géométrie directement en multilinestring + -- en mergeant les lignes le plus possible + tables.lines:insert({ + geom = object:as_multilinestring():line_merge() + }) + end +end + +function osm2pgsql.process_relation(object) + if clean_tags(object.tags) then + return + end + + local relation_type = object:grab_tag('type') + + -- Store route relations as multilinestrings + if relation_type == 'route' or relation_type == 'associatedStreet' or relation_type == 'public_transport' or relation_type == 'waterway' then + tables.lines:insert({ + geom = object:as_multilinestring():line_merge() + }) + return + end + + -- Store multipolygon and boundary relations as polygons + if relation_type == 'multipolygon' or relation_type == 'boundary' then + local geom = object:as_multipolygon() + tables.polygons:insert({ + geom = geom, + area = geom:spherical_area() + }) + end +end + diff --git a/backends/postgres_osm2pgsql/postgres_osm2pgsql.rb b/backends/postgres_osm2pgsql/postgres_osm2pgsql.rb new file mode 100644 index 0000000..4d0eec8 --- /dev/null +++ b/backends/postgres_osm2pgsql/postgres_osm2pgsql.rb @@ -0,0 +1,21 @@ +# frozen_string_literal: true + +require 'pg' +require 'overpass_parser/sql_dialect/postgres' + +class PostgresOsm2pgsql + def initialize + + @@con = PG.connect(ENV['DATABASE_URL']) + @@con.query(File.read(File.dirname(__FILE__) + '/view.sql')) + @dialect = OverpassParser::SqlDialect::Postgres.new(postgres_escape_literal: ->(s) { @@con.escape_literal(s) }) + end + + def exec(query) + request = OverpassParser.parse(query) + sql = request.to_sql(@dialect) + puts sql + result = @@con.exec(sql) + [sql, result.collect { |row| row['j'].gsub('+00:00', 'Z') }] + end +end diff --git a/backends/postgres_osm2pgsql/view.sql b/backends/postgres_osm2pgsql/view.sql new file mode 100644 index 0000000..3bf434e --- /dev/null +++ b/backends/postgres_osm2pgsql/view.sql @@ -0,0 +1,156 @@ +/************** ABOUT TABLES *****************/ +/* +- without the --slim option, only "output" tables are created (PREFIX_point PREFIX_line and PREFIX_polygon in the case of the deprecated pgsql output) and they contain elements filtered based on their tags (using list and parameters in .style file). These tables also contain the geometry. +- with --slim, 3 other "middle" tables containing ALL the raw OSM elements are created : _nodes, _ways, _rels +*/ + +/************** ABOUT GEOMETRY *****************/ +/* +Underpass as Overpass uses SRID 4326 whereas osm2pgsql uses by default SRID 3857 +To make Underpass works on your osm2pgsl database, you have to CREATE it with option --proj=4326 (for the case of deprecated pgsql output) or define that the tables will use SRID 4326 (for the case of the modern flex output) +If you want to deploy Underpass on an existing osm2pgsl database, you will have to modify both this backend and overpass_parser-rb, so that the parser transforms bbox and areas and others in SRID 3857 to allow comparison with the geom in your DB +*/ + +/************** ABOUT TAGS COLUMNS *****************/ +/* +- tags in "middle" tables _nodes, _ways, _rels are identical to the ones in OSM (they are "raw data" tables) +- but tags in "output" tables are always (slightly) different depending on the hstore options: + # With --hstore any tags without a column will be added to the hstore column. + # With --hstore-all all tags are added to the hstore column unless they appear in the style file with a delete flag +*/ + +/************** ABOUT METADATA *****************/ +/* adding metadata to the DB requires -x option */ +/* without it, all the CAST(tags->...) will return NULL */ + + +/******** UNION LINES AND POLYGONS **********/ +CREATE OR REPLACE TEMP VIEW lines_and_polygons AS +SELECT id, geom, NULL::real as area FROM lines +UNION ALL +SELECT * FROM polygons +; + + +/************** NODES *****************/ +/* requires database creation with either : + - option --slim without --flat-nodes + - options --slim --flat-nodes FILE --middle-with-nodes */ +CREATE OR REPLACE TEMP VIEW node AS +SELECT + n.id AS id, + n.version AS version, + n.created AS created, + n.changeset_id AS changeset, + n.user_id AS uid, + u.name AS user, + /* if you did not use --extra-attributes, replace above lines by + NULL::integer AS version, + NULL::timestamp without time zone AS created, + NULL::bigint AS changeset, + NULL::integer AS uid, + NULL::text AS user, + */ + n.tags AS tags, + NULL::bigint[] AS nodes, + NULL::jsonb AS members, + p.geom AS geom, + NULL::real AS area, + 'n' AS osm_type +FROM planet_osm_nodes as n +LEFT JOIN planet_osm_users AS u ON n.user_id = u.id /* also remove this line */ +LEFT JOIN points AS p ON n.id = p.id +; + + +/************** WAYS *****************/ +CREATE OR REPLACE TEMP VIEW way AS +SELECT + w.id AS id, + w.version AS version, + w.created AS created, + w.changeset_id AS changeset, + w.user_id AS uid, + u.name AS user, + /* if you did not use --extra-attributes, replace above lines by + NULL::integer AS version, + NULL::timestamp without time zone AS created, + NULL::bigint AS changeset, + NULL::integer AS uid, + NULL::text AS user, + */ + w.tags as tags, + w.nodes AS nodes, + NULL::jsonb AS members, + lp.geom AS geom, + lp.area AS area, + 'w' AS osm_type +FROM planet_osm_ways AS w +LEFT JOIN planet_osm_users AS u ON w.user_id = u.id /* also remove this line */ +LEFT JOIN lines_and_polygons AS lp ON w.id = lp.id +; + + +/************** RELATIONS *****************/ +/* complete version (based on table _rels) if you used --slim */ +CREATE OR REPLACE TEMP VIEW relation AS +SELECT + r.id AS id, + r.version AS version, + r.created AS created, + r.changeset_id AS changeset, + r.user_id AS uid, + u.name AS user, + /* if you did not use --extra-attributes, replace above lines by + NULL::integer AS version, + NULL::timestamp without time zone AS created, + NULL::bigint AS changeset, + NULL::integer AS uid, + NULL::text AS user, + */ + r.tags as tags, + NULL::bigint[] AS nodes, + r.members AS members, + lp.geom AS geom, + lp.area AS area, + 'r' AS osm_type +FROM planet_osm_rels AS r +LEFT JOIN planet_osm_users AS u ON r.user_id = u.id /* also remove this line */ +LEFT JOIN lines_and_polygons AS lp ON r.id = -lp.id +; + + +/************** NWR *****************/ +CREATE OR REPLACE TEMP VIEW nwr AS +SELECT * FROM node +UNION ALL +SELECT * FROM way +UNION ALL +SELECT * FROM relation +; + +/************** AREA *****************/ +CREATE OR REPLACE TEMP VIEW area AS +SELECT + CASE + WHEN osm_type='r' THEN 3600000000+id /* transform if of relations to be consistent with overpass */ + ELSE id + END AS id, + version, + created, + changeset, + uid, + user, + tags, + nodes, + members, + geom, + area, + REPLACE(osm_type, 'w', 'a') AS osm_type + /*CASE + WHEN osm_type='r' THEN 'a' /* transform r in a for underpass ? */ + ELSE osm_type + END AS osm_type,*/ +FROM nwr +WHERE area IS NOT NULL +; \ No newline at end of file diff --git a/config.ru b/config.ru index a41447b..aac3890 100644 --- a/config.ru +++ b/config.ru @@ -10,6 +10,8 @@ when 'DuckdbQuackosm' require_relative 'backends/duckdb_quackosm/duckdb_quackosm' when 'PostgresOsmosis' require_relative 'backends/postgres_osmosis/postgres_osmosis' +when 'PostgresOsm2pgsql' + require_relative 'backends/postgres_osm2pgsql/postgres_osm2pgsql' end class App < Hanami::API From b064726548453360225a2c1b18ef3aa0a363cd67 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Etil=C3=A8ne=20Jourdier?= Date: Thu, 10 Apr 2025 22:50:22 +0200 Subject: [PATCH 2/2] rewrite flex.lua and view.sql to solve index issue with negative ids --- backends/postgres_osm2pgsql/README.md | 44 ++++++++- .../postgres_osm2pgsql/geometries-alone.lua | 89 ++++++------------- backends/postgres_osm2pgsql/view.sql | 71 +++++---------- 3 files changed, 88 insertions(+), 116 deletions(-) diff --git a/backends/postgres_osm2pgsql/README.md b/backends/postgres_osm2pgsql/README.md index b16f29b..df5c44d 100644 --- a/backends/postgres_osm2pgsql/README.md +++ b/backends/postgres_osm2pgsql/README.md @@ -7,20 +7,56 @@ docker compose --profile '*' build ## Prepare the data -Create you database with osm2pgsql, using the script `geometries-alone.lua` in this folder. +### 1. View for a new, dedicated, updatable and complete DB -Example command : +This view is configured to be a true alternative to overpass, in the sense that there is no filtering on the elements included in the DB. They are all included in the DB with all their tags, whereas osm2pgsql is usually configured not to include tags or elements that are useless for generating tiles. +Warning : this wiew will not work on an existing osm2pgsql database (see below). It is specific for a database created with the lua script above and the `-s (--slim)` option. + +Create you database with osm2pgsql, using the script `geometries-alone.lua` available in this folder. + +Example command: + +``` +osm2pgsql -U user -d database -c -s --flat-nodes FILE --middle-with-nodes -x -O flex -S geometries-alone.lua extract.osm.pbf +``` + +Explanation of the command: +- `-c -s -x`: create an updatable table including metadata +- `--flat-nodes FILE --middle-with-nodes`: use the file `FILE` to store nodes (to reduce the size of the DB), but nodes with tags are also stored in the database (so that filtering by tag will be possible on nodes) +- `-O flex -S geometries-alone.lua`: use flex output mode with specific `.lua` file + +One finished, add index for tags: ``` -osm2pgsql -U user -d database -c -s --flat-nodes DB-flat-nodes --middle-with-nodes -x -O flex -S geometries-alone.lua extract.osm.pbf +CREATE INDEX nodes_tags_idx ON planet_osm_nodes USING GIN (tags); +CREATE INDEX ways_tags_idx ON planet_osm_ways USING GIN (tags); +CREATE INDEX rels_tags_idx ON planet_osm_rels USING GIN (tags); ``` -Warning : this backend will not work on a existing osm2pgsql database. it is specific for a database created with the lua script above and the `-s (--slim)` option. +Use `osm2pgsql-replication` to update the DB. + +Sizing +- 57GB for France (29GB for middle tables (metadata+tags) + 2GB for tag index + 26GB for output tables (geometries)) If your database was created "outside" docker, you will have to modify `docker-compose.yaml` to: - delete services `osm2pgsql` and `postgress` - in service api : delete reference `depends on: -postgres` and set your `DATABASE_URL: postgres://user:pw@host:5432/database` +Explanation of the `.lua` script and principle of the DB structure: +- `-s` option creates `middle` tables which include all raw OSM elements (`planet_osm_nodes`, `planet_osm_ways`, `planet_osm_rels`) with all their tags. This view uses these 3 tables to get tags (no need to duplicate them in `output` tables), but we need to manually index them at the beginning. +- `-x` option add columns for metadata in these tables, and table `planet_osm_users` for usernames. +- so only the geometries are missing. The `.lua` script of the `flex output` creates 3 additionnal `output` tables: `nodes_geom`, `ways_geom` and `rels_geom` with the id and the geometry. + - I had to use tables by element type instead of geometry type (as usual for osm2pgsql) since the negative id used for relations in area type table is problematic for the join with the `planet_osm_rels` table which uses normal positive id (join is slow since indexing is not working). +- For a list of expected areas (as usual in osm2pgsql), the lua script creates polygon-like geometries (instead of line-like) and adds the area size in a 3rd column (it will be usefull to get areas). + +### 2. View for an existing DB created for cartocss + +not written yet + +### 3. View for a simple static DB (without synchronisation) + +not written yet + ## Run the server Run the HTTP server diff --git a/backends/postgres_osm2pgsql/geometries-alone.lua b/backends/postgres_osm2pgsql/geometries-alone.lua index b198d2f..4dee89c 100644 --- a/backends/postgres_osm2pgsql/geometries-alone.lua +++ b/backends/postgres_osm2pgsql/geometries-alone.lua @@ -1,51 +1,34 @@ -- This is a very simple Lua config for the Flex output -- which only stores the geometries (not even the tags) --- for use with Underpass-API to mimics Overpass +-- for use with Underpass-API to mimic Overpass local tables = {} -tables.points = osm2pgsql.define_table({ - name = 'points', - ids = { type = 'node', id_column = 'id' }, +tables.nodes_geom = osm2pgsql.define_table({ + name = 'nodes_geom', + ids = { type = 'node', id_column = 'id', create_index='unique' }, columns = { - -- { column = 'tags', type = 'jsonb' }, { column = 'geom', type = 'point', projection = 4326, not_null = true } }}) -tables.lines = osm2pgsql.define_table({ - name = 'lines', - ids = { type = 'way', id_column = 'id' }, +tables.ways_geom = osm2pgsql.define_table({ + name = 'ways_geom', + ids = { type = 'way', id_column = 'id', create_index='unique' }, columns = { - -- { column = 'tags', type = 'jsonb' }, - { column = 'geom', type = 'multilinestring', projection = 4326, not_null = true } + { column = 'geom', type = 'geometry', projection = 4326, not_null = true }, + { column = 'area', type = 'real' } }}) -tables.polygons = osm2pgsql.define_table({ - name = 'polygons', - ids = { type = 'area', id_column = 'id' }, +tables.rels_geom = osm2pgsql.define_table({ + name = 'rels_geom', + ids = { type = 'relation', id_column = 'id', create_index='unique' }, columns = { - -- { column = 'tags', type = 'jsonb' }, { column = 'geom', type = 'geometry', projection = 4326, not_null = true }, - -- In this column we'll put the true area calculated on the spheroid { column = 'area', type = 'real' } }}) --- Helper function to remove some of the tags we usually are not interested in. --- Returns true if there are no tags left. - --- modifié : retourne vrai si aucun tag -local function clean_tags(tags) - -- tags.odbl = nil - -- tags.created_by = nil - -- tags.source = nil - -- tags['source:ref'] = nil - - return next(tags) == nil -end - --- Helper function that looks at the tags and decides if this is possibly --- an area. +-- Helper function that looks at the tags and decides if this is possibly an area local function has_area_tags(tags) if tags.area == 'yes' or tags.area == 'true' or tags.area == '1' then return true @@ -82,65 +65,49 @@ local function has_area_tags(tags) or tags['area:highway'] end +-- Store geometry of nodes (so that they can be indexed) function osm2pgsql.process_node(object) - if clean_tags(object.tags) then - return - end - - local geom = object:as_point() - - tables.points:insert({ - -- tags = object.tags, - geom = geom -- the point will be automatically be projected to 3857 + tables.nodes_geom:insert({ + geom = object:as_point() }) - end + function osm2pgsql.process_way(object) - if clean_tags(object.tags) then - return - end -- A closed way that also has the right tags for an area is a polygon. if object.is_closed and has_area_tags(object.tags) then -- Creating the polygon geometry takes time, so we do it once here -- and later store it in the table and use it to calculate the area. local geom = object:as_polygon() - tables.polygons:insert({ + tables.ways_geom:insert({ geom = geom, area = geom:spherical_area() -- calculate "real" area in spheroid }) else - -- modif : on enregistre la géométrie directement en multilinestring - -- en mergeant les lignes le plus possible - tables.lines:insert({ - geom = object:as_multilinestring():line_merge() + -- Store way as line + tables.ways_geom:insert({ + geom = object:as_linestring() }) end end function osm2pgsql.process_relation(object) - if clean_tags(object.tags) then - return - end local relation_type = object:grab_tag('type') - -- Store route relations as multilinestrings - if relation_type == 'route' or relation_type == 'associatedStreet' or relation_type == 'public_transport' or relation_type == 'waterway' then - tables.lines:insert({ - geom = object:as_multilinestring():line_merge() - }) - return - end - - -- Store multipolygon and boundary relations as polygons + -- Store multipolygon and boundary relations as multipolygons, with their area if relation_type == 'multipolygon' or relation_type == 'boundary' then local geom = object:as_multipolygon() - tables.polygons:insert({ + tables.rels_geom:insert({ geom = geom, area = geom:spherical_area() }) + else + -- Store other relations as geometryCollection + tables.rels_geom:insert({ + geom = object:as_geometrycollection() + }) end end diff --git a/backends/postgres_osm2pgsql/view.sql b/backends/postgres_osm2pgsql/view.sql index 3bf434e..cee9223 100644 --- a/backends/postgres_osm2pgsql/view.sql +++ b/backends/postgres_osm2pgsql/view.sql @@ -1,41 +1,18 @@ -/************** ABOUT TABLES *****************/ +/************** WARNING *****************/ /* -- without the --slim option, only "output" tables are created (PREFIX_point PREFIX_line and PREFIX_polygon in the case of the deprecated pgsql output) and they contain elements filtered based on their tags (using list and parameters in .style file). These tables also contain the geometry. -- with --slim, 3 other "middle" tables containing ALL the raw OSM elements are created : _nodes, _ways, _rels +This view is specific for a new database created with flex output geometries-alone.lua */ -/************** ABOUT GEOMETRY *****************/ -/* -Underpass as Overpass uses SRID 4326 whereas osm2pgsql uses by default SRID 3857 -To make Underpass works on your osm2pgsl database, you have to CREATE it with option --proj=4326 (for the case of deprecated pgsql output) or define that the tables will use SRID 4326 (for the case of the modern flex output) -If you want to deploy Underpass on an existing osm2pgsl database, you will have to modify both this backend and overpass_parser-rb, so that the parser transforms bbox and areas and others in SRID 3857 to allow comparison with the geom in your DB -*/ -/************** ABOUT TAGS COLUMNS *****************/ +/************** ABOUT TABLES *****************/ /* -- tags in "middle" tables _nodes, _ways, _rels are identical to the ones in OSM (they are "raw data" tables) -- but tags in "output" tables are always (slightly) different depending on the hstore options: - # With --hstore any tags without a column will be added to the hstore column. - # With --hstore-all all tags are added to the hstore column unless they appear in the style file with a delete flag +The flex output lua script creates: +- the 3 normal "middle" tables planet_osm_nodes, _ ways and _rels which include (all ans synchronised) OSM elements with (all) their tags and metadata. (tags need to be indexed after DB creation). And also _users table +- 3 additionnal "output" tables to store the geometries using SRID 4326 (to be compatible with overpass). 1 table per element type : nodes_geom, ways_geom and rels_geom +- the views join middle table (tags) with the corresponding output table (geometry) and also with users table (username) */ -/************** ABOUT METADATA *****************/ -/* adding metadata to the DB requires -x option */ -/* without it, all the CAST(tags->...) will return NULL */ - - -/******** UNION LINES AND POLYGONS **********/ -CREATE OR REPLACE TEMP VIEW lines_and_polygons AS -SELECT id, geom, NULL::real as area FROM lines -UNION ALL -SELECT * FROM polygons -; - - /************** NODES *****************/ -/* requires database creation with either : - - option --slim without --flat-nodes - - options --slim --flat-nodes FILE --middle-with-nodes */ CREATE OR REPLACE TEMP VIEW node AS SELECT n.id AS id, @@ -44,7 +21,7 @@ SELECT n.changeset_id AS changeset, n.user_id AS uid, u.name AS user, - /* if you did not use --extra-attributes, replace above lines by + /* if you did not use -x to get metadata, replace above lines by NULL::integer AS version, NULL::timestamp without time zone AS created, NULL::bigint AS changeset, @@ -54,15 +31,14 @@ SELECT n.tags AS tags, NULL::bigint[] AS nodes, NULL::jsonb AS members, - p.geom AS geom, + g.geom AS geom, NULL::real AS area, 'n' AS osm_type FROM planet_osm_nodes as n LEFT JOIN planet_osm_users AS u ON n.user_id = u.id /* also remove this line */ -LEFT JOIN points AS p ON n.id = p.id +LEFT JOIN nodes_geom AS g ON n.id = g.id ; - /************** WAYS *****************/ CREATE OR REPLACE TEMP VIEW way AS SELECT @@ -72,7 +48,7 @@ SELECT w.changeset_id AS changeset, w.user_id AS uid, u.name AS user, - /* if you did not use --extra-attributes, replace above lines by + /* if you did not use -x to get metadata, replace above lines by NULL::integer AS version, NULL::timestamp without time zone AS created, NULL::bigint AS changeset, @@ -82,17 +58,15 @@ SELECT w.tags as tags, w.nodes AS nodes, NULL::jsonb AS members, - lp.geom AS geom, - lp.area AS area, + g.geom AS geom, + g.area AS area, 'w' AS osm_type FROM planet_osm_ways AS w LEFT JOIN planet_osm_users AS u ON w.user_id = u.id /* also remove this line */ -LEFT JOIN lines_and_polygons AS lp ON w.id = lp.id +LEFT JOIN ways_geom AS g ON w.id = g.id ; - /************** RELATIONS *****************/ -/* complete version (based on table _rels) if you used --slim */ CREATE OR REPLACE TEMP VIEW relation AS SELECT r.id AS id, @@ -101,7 +75,7 @@ SELECT r.changeset_id AS changeset, r.user_id AS uid, u.name AS user, - /* if you did not use --extra-attributes, replace above lines by + /* if you did not use -x to get metadata, replace above lines by NULL::integer AS version, NULL::timestamp without time zone AS created, NULL::bigint AS changeset, @@ -111,15 +85,14 @@ SELECT r.tags as tags, NULL::bigint[] AS nodes, r.members AS members, - lp.geom AS geom, - lp.area AS area, + g.geom AS geom, + g.area AS area, 'r' AS osm_type FROM planet_osm_rels AS r LEFT JOIN planet_osm_users AS u ON r.user_id = u.id /* also remove this line */ -LEFT JOIN lines_and_polygons AS lp ON r.id = -lp.id +LEFT JOIN rels_geom AS g ON r.id = g.id ; - /************** NWR *****************/ CREATE OR REPLACE TEMP VIEW nwr AS SELECT * FROM node @@ -129,11 +102,11 @@ UNION ALL SELECT * FROM relation ; -/************** AREA *****************/ +/************** AREAS *****************/ CREATE OR REPLACE TEMP VIEW area AS SELECT CASE - WHEN osm_type='r' THEN 3600000000+id /* transform if of relations to be consistent with overpass */ + WHEN osm_type='r' THEN 3600000000+id /* transform id of relations to be consistent with overpass */ ELSE id END AS id, version, @@ -147,10 +120,6 @@ SELECT geom, area, REPLACE(osm_type, 'w', 'a') AS osm_type - /*CASE - WHEN osm_type='r' THEN 'a' /* transform r in a for underpass ? */ - ELSE osm_type - END AS osm_type,*/ FROM nwr WHERE area IS NOT NULL ; \ No newline at end of file