Transportation generalization table optimization and cleanup (#1172)

This PR updates the `transportation` layer creation scripts to simplify the SQL and remove unneeded sub-selects, checks and conditionals, fix indexes, and improve inline documentation. 

Currently, there are two sequences of materialized view creations.  There is one from zoom 11 through 9, and a second one for zoom 8 through 4.  This PR removes that break in the sequence of transportation table materialized view creations, in favor of one in which high-zoom views are created first, and then each lower zoom is created from the zoom above.

Instead, the current generalized zoom 8 transportation table is built directly from `osm_transportation_linestring` rather than being built from the zoom 9 transportation table.  This means that when building the zoom 8 table, it must scan the entire transportation network rather than just selecting from the pre-filtered zoom 9 table.

This PR removes an unneeded sub-select in the build of the zoom 8 table, which appears to be a leftover from an old version of the SQL that did some sort of merge.  Once this PR is implemented all zooms from 11 through 4 will be linked via a progressive series of materialized views.

Lastly, this adds in missing materialized view refreshes for zooms 9-11, which appear to have been entirely missing, and as far as I can tell aren't getting updated in the current version of this code.

In addition, the following optimizations were added as part of this commit:

1. Updates the `osm_highway_linestring_highway_partial_idx` partial index to match the `SELECT..WHERE` clause actually present in `transportation/update_route_member.sql`, which is where it appears to be actually used, and update inline documentation to reflect this.

2. Collapses unnecessary sub-select block in `osm_transportation_merge_linestring_gen_z11`, and removes unnecessary ST_IsValid() call, which already provided in `mapping.yaml`, and update inline documentation to reflect these assumptions.

3. Updates `WHERE` blocks to remove unnecesary checks and further document assumptions.  The `highway=construction` check is unnecessary in all cases, because it is sufficient to check the `construction` key alone.  If `construction=*` is set, then `highway=construction` is implied.

4. Two indexes were added to `layers/transportation/update_route_member.sql` to improve route population performance.

In testing locally, I'm seeing performance improvements around 10% in the generation of the `transportation` layer, based on modifying `openmaptiles.yaml` to generate only the transportation layer and then repeatedly running `time make import-sql`, however, this timing might be impacted by docker, so I would ask for confirmation of acceptable performance.

In addition, this PR shortens the length of the transportation update SQL file by 30 lines, which makes it easier for contributors to work with.
pull/1174/head
Brian Sperlongano 2021-08-13 12:00:33 -04:00 zatwierdzone przez GitHub
rodzic f78d42ec84
commit fdb9ae58cd
Nie znaleziono w bazie danych klucza dla tego podpisu
ID klucza GPG: 4AEE18F83AFDEB23
3 zmienionych plików z 25 dodań i 52 usunięć

Plik binarny nie jest wyświetlany.

Przed

Szerokość:  |  Wysokość:  |  Rozmiar: 529 KiB

Po

Szerokość:  |  Wysokość:  |  Rozmiar: 556 KiB

Wyświetl plik

@ -77,6 +77,9 @@ CREATE INDEX IF NOT EXISTS osm_route_member_ref_idx ON osm_route_member ("ref");
CREATE INDEX IF NOT EXISTS osm_route_member_network_type_idx ON osm_route_member ("network_type");
CREATE INDEX IF NOT EXISTS osm_highway_linestring_osm_id_idx ON osm_highway_linestring ("osm_id");
CREATE INDEX IF NOT EXISTS osm_highway_linestring_gen_z11_osm_id_idx ON osm_highway_linestring_gen_z11 ("osm_id");
ALTER TABLE osm_route_member ADD COLUMN IF NOT EXISTS concurrency_index int;
INSERT INTO osm_route_member (id, concurrency_index)

Wyświetl plik

@ -7,16 +7,16 @@ DROP TRIGGER IF EXISTS trigger_refresh ON transportation.updates;
-- Because this works well for roads that do not have relations as well
-- Improve performance of the sql in transportation_name/network_type.sql
-- Improve performance of the sql in transportation/update_route_member.sql
CREATE INDEX IF NOT EXISTS osm_highway_linestring_highway_partial_idx
ON osm_highway_linestring (highway)
WHERE highway IN ('motorway', 'trunk', 'primary', 'construction');
WHERE highway IN ('motorway', 'trunk');
-- etldoc: osm_highway_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z11
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z11 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z11 AS
(
SELECT (ST_Dump(geometry)).geom AS geometry,
SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry,
NULL::bigint AS osm_id,
highway,
network,
@ -24,36 +24,20 @@ SELECT (ST_Dump(geometry)).geom AS geometry,
is_bridge,
is_tunnel,
is_ford,
z_order,
min(z_order) as z_order,
bicycle,
foot,
horse,
mtb_scale,
layer
FROM (
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
min(z_order) AS z_order,
bicycle,
foot,
horse,
mtb_scale,
layer
FROM osm_highway_linestring_gen_z11
WHERE ST_IsValid(geometry)
GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, bicycle, foot, horse, mtb_scale, layer
) AS highway_union
FROM osm_highway_linestring_gen_z11
-- mapping.yaml pre-filter: motorway/trunk/primary/secondary/tertiary, with _link variants, construction, ST_IsValid()
GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, bicycle, foot, horse, mtb_scale, layer
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z11_geometry_idx
ON osm_transportation_merge_linestring_gen_z11 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z11 -> osm_transportation_merge_linestring_gen_z10
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z10 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z10 AS
(
SELECT ST_Simplify(geometry, ZRes(12)) AS geometry,
@ -72,13 +56,12 @@ SELECT ST_Simplify(geometry, ZRes(12)) AS geometry,
layer
FROM osm_transportation_merge_linestring_gen_z11
WHERE highway NOT IN ('tertiary', 'tertiary_link')
OR highway = 'construction' AND construction NOT IN ('tertiary', 'tertiary_link')
OR construction NOT IN ('tertiary', 'tertiary_link')
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z10_geometry_idx
ON osm_transportation_merge_linestring_gen_z10 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z10 -> osm_transportation_merge_linestring_gen_z9
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z9 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z9 AS
(
SELECT ST_Simplify(geometry, ZRes(11)) AS geometry,
@ -96,17 +79,15 @@ SELECT ST_Simplify(geometry, ZRes(11)) AS geometry,
mtb_scale,
layer
FROM osm_transportation_merge_linestring_gen_z10
WHERE highway NOT IN ('tertiary', 'tertiary_link')
OR highway = 'construction' AND construction NOT IN ('tertiary', 'tertiary_link')
-- Current view: motorway/primary/secondary, with _link variants and construction
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z9_geometry_idx
ON osm_transportation_merge_linestring_gen_z9 USING gist (geometry);
-- etldoc: osm_highway_linestring -> osm_transportation_merge_linestring_gen_z8
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z8 CASCADE;
-- etldoc: osm_transportation_merge_linestring_gen_z9 -> osm_transportation_merge_linestring_gen_z8
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z8 AS
(
SELECT ST_Simplify((ST_Dump(geometry)).geom, ZRes(10)) AS geometry,
SELECT ST_Simplify(ST_LineMerge(ST_Collect(geometry)), ZRes(10)) AS geometry,
NULL::bigint AS osm_id,
highway,
network,
@ -114,28 +95,17 @@ SELECT ST_Simplify((ST_Dump(geometry)).geom, ZRes(10)) AS geometry,
is_bridge,
is_tunnel,
is_ford,
z_order
FROM (
SELECT ST_LineMerge(ST_Collect(geometry)) AS geometry,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
min(z_order) AS z_order
FROM osm_highway_linestring
WHERE (highway IN ('motorway', 'trunk', 'primary') OR
highway = 'construction' AND construction IN ('motorway', 'trunk', 'primary'))
AND ST_IsValid(geometry)
GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford
) AS highway_union
min(z_order) as z_order
FROM osm_transportation_merge_linestring_gen_z9
WHERE (highway IN ('motorway', 'trunk', 'primary') OR
construction IN ('motorway', 'trunk', 'primary'))
AND ST_IsValid(geometry)
GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z8_geometry_idx
ON osm_transportation_merge_linestring_gen_z8 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z8 -> osm_transportation_merge_linestring_gen_z7
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z7 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z7 AS
(
SELECT ST_Simplify(geometry, ZRes(9)) AS geometry,
@ -155,7 +125,6 @@ CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_geometry_i
ON osm_transportation_merge_linestring_gen_z7 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z7 -> osm_transportation_merge_linestring_gen_z6
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z6 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z6 AS
(
SELECT ST_Simplify(geometry, ZRes(8)) AS geometry,
@ -168,14 +137,13 @@ SELECT ST_Simplify(geometry, ZRes(8)) AS geometry,
is_ford,
z_order
FROM osm_transportation_merge_linestring_gen_z7
WHERE (highway IN ('motorway', 'trunk') OR highway = 'construction' AND construction IN ('motorway', 'trunk'))
WHERE (highway IN ('motorway', 'trunk') OR construction IN ('motorway', 'trunk'))
AND ST_Length(geometry) > 100
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z6_geometry_idx
ON osm_transportation_merge_linestring_gen_z6 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z6 -> osm_transportation_merge_linestring_gen_z5
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z5 AS
(
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry,
@ -195,7 +163,6 @@ CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_geometry_i
ON osm_transportation_merge_linestring_gen_z5 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z5 -> osm_transportation_merge_linestring_gen_z4
DROP MATERIALIZED VIEW IF EXISTS osm_transportation_merge_linestring_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z4 AS
(
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry,
@ -208,7 +175,7 @@ SELECT ST_Simplify(geometry, ZRes(6)) AS geometry,
is_ford,
z_order
FROM osm_transportation_merge_linestring_gen_z5
WHERE (highway = 'motorway' OR highway = 'construction' AND construction = 'motorway')
WHERE (highway = 'motorway' OR construction = 'motorway')
AND ST_Length(geometry) > 1000
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z4_geometry_idx
@ -239,6 +206,9 @@ DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh transportation';
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z11;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z10;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z9;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z8;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z7;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z6;