Skip to content

Commit

Permalink
Use md5 for unique id in mviews
Browse files Browse the repository at this point in the history
  • Loading branch information
Rub21 committed Feb 8, 2025
1 parent 854455c commit 62e91f6
Showing 1 changed file with 116 additions and 72 deletions.
188 changes: 116 additions & 72 deletions images/tiler-imposm/queries/transport_lines_mviews.sql
Original file line number Diff line number Diff line change
@@ -1,99 +1,143 @@
DO $$
DECLARE
transport_tables JSONB := '[
{"lines": "osm_transport_lines_z5_7", "multilines": "osm_transport_multilines_z5_7", "mview": "mview_transport_lines_z5_7"},
{"lines": "osm_transport_lines_z8_9", "multilines": "osm_transport_multilines_z8_9", "mview": "mview_transport_lines_z8_9"},
{"lines": "osm_transport_lines_z10_11", "multilines": "osm_transport_multilines_z10_11", "mview": "mview_transport_lines_z10_11"},
{"lines": "osm_transport_lines_z12_13", "multilines": "osm_transport_multilines_z12_13", "mview": "mview_transport_lines_z12_13"},
{"lines": "osm_transport_lines", "multilines": "osm_transport_multilines", "mview": "mview_transport_lines_z14_20"}
]'::JSONB;

table_entry JSONB;
zoom_levels TEXT[] := ARRAY['_z5_7', '_z8_9', '_z10_11', '_z12_13', '_z14_20'];
zoom TEXT;
sql_drop TEXT;
sql_create TEXT;
sql_unique_index TEXT;
sql_geometry TEXT;
column_list TEXT := '
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';

lines_table TEXT;
multilines_table TEXT;
BEGIN
RAISE NOTICE 'Starting materialized view creation process...';

FOR table_entry IN SELECT * FROM jsonb_array_elements(transport_tables)
FOR zoom IN SELECT UNNEST(zoom_levels)
LOOP
RAISE NOTICE 'Processing: %', table_entry;
-- Special case for _z14_20, use base tables without zoom suffix
IF zoom = '_z14_20' THEN
lines_table := 'osm_transport_lines';
multilines_table := 'osm_transport_multilines';
ELSE
lines_table := format('osm_transport_lines%s', zoom);
multilines_table := format('osm_transport_multilines%s', zoom);
END IF;

RAISE NOTICE 'Processing: {"lines": "%s", "mview": "mview_transport_lines%s", "multilines": "%s"}',
lines_table, zoom, multilines_table;

-- Drop materialized view if it exists
sql_drop := format('DROP MATERIALIZED VIEW IF EXISTS %s CASCADE;', table_entry->>'mview');
RAISE NOTICE 'Executing: %', sql_drop;
sql_drop := format('DROP MATERIALIZED VIEW IF EXISTS mview_transport_lines%s CASCADE;', zoom);
RAISE NOTICE 'Executing: %s', sql_drop;
EXECUTE sql_drop;

RAISE NOTICE 'Creating materialized view: mview_transport_lines%s', zoom;

-- Construct the SQL query using a CTE
-- Construct the SQL query to create the materialized view
sql_create := format(
'CREATE MATERIALIZED VIEW %s AS
WITH selected_columns AS (
SELECT
''way_'' || CAST(lines.osm_id AS TEXT) AS osm_id,
%s,
''%s'' AS source_table
FROM %s AS lines
WHERE lines.geometry IS NOT NULL
UNION ALL
SELECT DISTINCT ON (multilines.osm_id, multilines.member)
''relation_'' || CAST(multilines.osm_id AS TEXT) || ''_'' || COALESCE(CAST(multilines.member AS TEXT), '''') AS osm_id,
%s,
''%s'' AS source_table
FROM %s AS multilines
WHERE ST_GeometryType(multilines.geometry) = ''ST_LineString''
AND multilines.geometry IS NOT NULL
)
SELECT * FROM selected_columns;',
table_entry->>'mview', column_list, table_entry->>'lines', table_entry->>'lines',
column_list, table_entry->>'multilines', table_entry->>'multilines'
'CREATE MATERIALIZED VIEW mview_transport_lines%s AS
SELECT
md5(COALESCE(CAST(osm_id AS TEXT), '''') || ''_'' || COALESCE(type, '''')) 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,
NULL AS member, -- No member in osm_transport_lines
''osm_transport_lines'' AS source_table
FROM %s
WHERE geometry IS NOT NULL
UNION ALL
SELECT
md5(COALESCE(CAST(osm_id AS TEXT), '''') || ''_'' || COALESCE(CAST(member AS TEXT), '''') || ''_'' || COALESCE(type, '''')) 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,
member, -- Include member from osm_transport_multilines
''osm_transport_multilines'' AS source_table
FROM %s
WHERE ST_GeometryType(geometry) = ''ST_LineString''
AND geometry IS NOT NULL;',
zoom, lines_table, multilines_table
);

RAISE NOTICE 'Creating materialized view: %', table_entry->>'mview';
RAISE NOTICE 'Executing materialized view creation SQL for: mview_transport_lines%s', zoom;
EXECUTE sql_create;

-- Create UNIQUE index to prevent duplicates

RAISE NOTICE 'Successfully created materialized view: mview_transport_lines%s', zoom;
END LOOP;

RAISE NOTICE 'Materialized view creation process completed successfully!';
END $$;

DO $$
DECLARE
zoom_levels TEXT[] := ARRAY['_z5_7', '_z8_9', '_z10_11', '_z12_13', '_z14_20'];
zoom TEXT;
sql_unique_index TEXT;
sql_geometry TEXT;
BEGIN
RAISE NOTICE 'Starting index creation process...';

FOR zoom IN SELECT UNNEST(zoom_levels)
LOOP
RAISE NOTICE 'Processing indexes for: mview_transport_lines%s', zoom;

-- Create UNIQUE index using osm_id to allow CONCURRENT REFRESH
sql_unique_index := format(
'CREATE UNIQUE INDEX CONCURRENTLY idx_%s_osm_id ON %s (osm_id);',
table_entry->>'mview', table_entry->>'mview'
'CREATE UNIQUE INDEX IF NOT EXISTS idx_mview_transport_lines%s_osm_id
ON mview_transport_lines%s (osm_id);',
zoom, zoom
);
RAISE NOTICE 'Creating unique index: %', sql_unique_index;
RAISE NOTICE 'Executing: %s', sql_unique_index;
EXECUTE sql_unique_index;

-- Create spatial index on geometry
sql_geometry := format(
'CREATE INDEX CONCURRENTLY idx_%s_geom ON %s USING GIST (geometry);',
table_entry->>'mview', table_entry->>'mview'
'CREATE INDEX IF NOT EXISTS idx_mview_transport_lines%s_geom
ON mview_transport_lines%s USING GIST (geometry);',
zoom, zoom
);
RAISE NOTICE 'Creating spatial index: %', sql_geometry;
RAISE NOTICE 'Executing: %s', sql_geometry;
EXECUTE sql_geometry;

RAISE NOTICE 'Successfully created materialized view and indexes for %', table_entry->>'mview';
RAISE NOTICE 'Indexes successfully created for mview_transport_lines%s', zoom;
END LOOP;

RAISE NOTICE 'Materialized view creation process completed!';
END $$;
RAISE NOTICE 'Index creation process completed successfully!';
END $$;

0 comments on commit 62e91f6

Please # to comment.