Skip to content

Commit

Permalink
Add sql script to create materialized views fro transport lines
Browse files Browse the repository at this point in the history
  • Loading branch information
Rub21 committed Feb 7, 2025
1 parent 685a00f commit 167a5d9
Show file tree
Hide file tree
Showing 6 changed files with 129 additions and 16 deletions.
2 changes: 1 addition & 1 deletion images/tiler-imposm/Dockerfile
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,7 @@ RUN add-apt-repository ppa:deadsnakes/ppa && \
python3 -m pip install pip --upgrade && \
python3 -m pip install wheel

RUN apt-get update && apt-get install -y postgresql-client && \
RUN apt-get update && apt-get install -y postgresql-client postgresql-14-cron && \
rm -rf /var/lib/apt/lists/*

RUN wget -c https://dl.google.com/go/go1.21.0.linux-amd64.tar.gz -O - | tar -xz -C /usr/local
Expand Down
7 changes: 1 addition & 6 deletions images/tiler-imposm/config/layers/transport_lines.json
Original file line number Diff line number Diff line change
Expand Up @@ -24,14 +24,9 @@
"tolerance": 15
},
"transport_lines_z12_13": {
"source": "transport_lines_z14_20",
"source": "transport_lines",
"sql_filter": "type IN ('motorway', 'motorway_link', 'trunk', 'trunk_link', 'construction', 'primary', 'primary_link', 'secondary', 'secondary_link', 'tertiary', 'tertiary_link', 'miniature', 'narrow_gauge', 'dismantled', 'abandoned', 'disused', 'razed', 'rail', 'light_rail', 'preserved', 'proposed', 'tram', 'funicular', 'monorail', 'taxiway', 'runway', 'raceway', 'residential', 'service', 'unclassified') OR class IN ('railway', 'route')",
"tolerance": 5
},
"transport_lines_z14_20": {
"source": "transport_lines",
"sql_filter": null,
"tolerance": 0
}
},
"tables": {
Expand Down
115 changes: 115 additions & 0 deletions images/tiler-imposm/queries/transport_lines_mviews.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,115 @@
-- This is an SQL script to merge the transport lines and multilines tables into materialized views.
DO $$
DECLARE
zoom_levels TEXT[] := ARRAY['_z5_7', '_z8_9', '_z10_11', '_z12_13'];
zoom TEXT;
sql_drop TEXT;
sql_create TEXT;
BEGIN
FOR zoom IN SELECT UNNEST(zoom_levels)
LOOP
-- Drop materialized view if it exists
sql_drop := format('DROP MATERIALIZED VIEW IF EXISTS mview_transport_lines%s CASCADE;', zoom);
EXECUTE sql_drop;

-- Construct the SQL query to create the materialized view
sql_create := format(
'CREATE MATERIALIZED VIEW mview_transport_lines%s AS
SELECT
''way_'' || CAST(osm_id AS TEXT) AS osm_id,
geometry,
type,
name,
tunnel,
bridge,
oneway,
ref,
z_order,
access,
service,
ford,
class,
electrified,
highspeed,
usage,
railway,
aeroway,
highway,
route,
start_date,
end_date,
tags,
''osm_transport_lines'' AS source_table
FROM osm_transport_lines%s
WHERE geometry IS NOT NULL
UNION ALL
SELECT
''relation_'' || CAST(osm_id AS TEXT) || ''_'' || COALESCE(CAST(member AS TEXT), '''') AS osm_id,
geometry,
type,
name,
tunnel,
bridge,
oneway,
ref,
z_order,
access,
service,
ford,
class,
electrified,
highspeed,
usage,
railway,
aeroway,
highway,
route,
start_date,
end_date,
tags,
''osm_transport_multilines'' AS source_table
FROM osm_transport_multilines%s
WHERE ST_GeometryType(geometry) = ''ST_LineString''
AND geometry IS NOT NULL;',
zoom, zoom, zoom
);

-- Execute the dynamically generated SQL
EXECUTE sql_create;

-- Log success message
RAISE NOTICE 'Created materialized view: mview_transport_lines%s', zoom;
END LOOP;
END $$;



DO $$
DECLARE
zoom_levels TEXT[] := ARRAY['_z5_7', '_z8_9', '_z10_11', '_z12_13'];
zoom TEXT;
sql_osm_id TEXT;
sql_geometry TEXT;
BEGIN
FOR zoom IN SELECT UNNEST(zoom_levels)
LOOP
-- Create index on osm_id
sql_osm_id := format('CREATE INDEX idx_mview_transport_lines%s_osm_id ON mview_transport_lines%s (osm_id);', zoom, zoom);
EXECUTE sql_osm_id;

-- Create spatial index on geometry
sql_geometry := format('CREATE INDEX idx_mview_transport_lines%s_geom ON mview_transport_lines%s USING GIST (geometry);', zoom, zoom);
EXECUTE sql_geometry;

-- Log success message
RAISE NOTICE 'Indexes created on mview_transport_lines%s', zoom;
END LOOP;
END $$;


SELECT cron.schedule('refresh_transport_views', '*/2 * * * *', $$
REFRESH MATERIALIZED VIEW CONCURRENTLY mview_transport_lines_z5_7;
REFRESH MATERIALIZED VIEW CONCURRENTLY mview_transport_lines_z8_9;
REFRESH MATERIALIZED VIEW CONCURRENTLY mview_transport_lines_z10_11;
REFRESH MATERIALIZED VIEW CONCURRENTLY mview_transport_lines_z12_13;
$$);
5 changes: 4 additions & 1 deletion images/tiler-imposm/start.sh
Original file line number Diff line number Diff line change
Expand Up @@ -142,8 +142,11 @@ function updateData() {

# create views
echo "Create views"
psql $PG_CONNECTION -f queries/transport_lines_mviews.sql

python materialized_views.py &
local local_last_state_path="$DIFF_DIR/last.state.txt"

### Update the DB with the new data from minute replication
if [ "$OVERWRITE_STATE" = "true" ]; then
echo "Overwriting last.state.txt..."
Expand Down Expand Up @@ -218,7 +221,7 @@ function importData() {
# These index will help speed up tegola tile generation
psql $PG_CONNECTION -f queries/postgis_post_import.sql
psql $PG_CONNECTION -f queries/land_mviews.sql
# psql $PG_CONNECTION -f queries/postgis_helpers.sql
psql $PG_CONNECTION -f queries/transport_lines_mviews.sql

# To not import again
touch $INIT_FILE
Expand Down
2 changes: 1 addition & 1 deletion images/tiler-server/config/providers/transport_lines.toml
Original file line number Diff line number Diff line change
Expand Up @@ -142,7 +142,7 @@ SELECT
isodatetodecimaldate(pad_date(end_date, 'end'), FALSE) AS end_decdate,
{{LENGUAGES}}
FROM
osm_transport_lines_z14_20
osm_transport_lines
WHERE
geometry && !BBOX!
"""
Expand Down
14 changes: 7 additions & 7 deletions values.staging.template.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -392,10 +392,10 @@ osm-seed:
tilerDb:
enabled: true
useExternalHost: # When we are using useExternalHost.enabled= true other variables are giong to be disable ans use the external host config
enabled: true
enabled: false
env:
POSTGRES_HOST: {{STAGING_TILER_DB_HOST}}
POSTGRES_DB: tiler_osm_production # Kuberntes existing db called, tiler-osm
POSTGRES_DB: tiler_osm_staging # Kuberntes existing db called, tiler-osm
POSTGRES_USER: postgres
POSTGRES_PASSWORD: {{STAGING_TILER_DB_PASSWORD}}
POSTGRES_PORT: 5432
Expand All @@ -406,7 +406,7 @@ osm-seed:
mountPath: /var/lib/postgresql/data
subPath: postgresql-d
# In case cloudProvider: aws
AWS_ElasticBlockStore_volumeID : vol-099bf0d82fed03c8b
AWS_ElasticBlockStore_volumeID : vol-045cab2cfc3b5154d
AWS_ElasticBlockStore_size: 100Gi
resources:
enabled: false
Expand Down Expand Up @@ -487,12 +487,12 @@ osm-seed:
# ====================================================================================================

tilerImposm:
enabled: false
enabled: true
env:
TILER_IMPORT_FROM: osm
TILER_IMPORT_PBF_URL: https://s3.amazonaws.com/planet.openhistoricalmap.org/planet/planet-250117_0002.osm.pbf
TILER_IMPORT_PBF_URL: https://s3.amazonaws.com/planet.openhistoricalmap.org/planet/planet-250207_0001.osm.pbf
REPLICATION_URL: http://s3.amazonaws.com/planet.openhistoricalmap.org/replication/minute/
SEQUENCE_NUMBER: '1690000'
SEQUENCE_NUMBER: '1701000'
OVERWRITE_STATE: false
UPLOAD_EXPIRED_FILES: true
IMPORT_NATURAL_EARTH: true
Expand All @@ -503,7 +503,7 @@ osm-seed:
accessMode: ReadWriteOnce
mountPath: /mnt/data
# In case cloudProvider: aws
AWS_ElasticBlockStore_volumeID: vol-0b77b2c5e00d8f452
AWS_ElasticBlockStore_volumeID: vol-05b4435bac8bb37b4
AWS_ElasticBlockStore_size: 50Gi
resources:
enabled: false
Expand Down

0 comments on commit 167a5d9

Please # to comment.