openmaptiles/layers/transportation/update_transportation_merge...

312 wiersze
12 KiB
MySQL
Czysty Zwykły widok Historia

DROP TRIGGER IF EXISTS trigger_flag_transportation ON osm_highway_linestring;
DROP TRIGGER IF EXISTS trigger_refresh ON transportation.updates;
-- Instead of using relations to find out the road names we
-- stitch together the touching ways with the same name
-- to allow for nice label rendering
-- Because this works well for roads that do not have relations as well
-- etldoc: osm_highway_linestring -> osm_transportation_name_network
-- etldoc: osm_route_member -> osm_transportation_name_network
CREATE TABLE IF NOT EXISTS osm_transportation_name_network AS
SELECT
geometry,
osm_id,
tags,
ref,
highway,
subclass,
brunnel,
"level",
sac_scale,
layer,
indoor,
network_type,
route_1, route_2, route_3, route_4, route_5, route_6,
z_order,
route_rank
FROM (
SELECT DISTINCT ON (hl.osm_id)
hl.geometry,
hl.osm_id,
BUGFIX: Fix name-based way fragmentation in transportation_name (#1295) I discovered this bug while investigating issues with the updates process related to #1190 #1292, and #814. The `transportation_name` layer produces slightly different `tags` hstore values in the `osm_transportation_name_linestring` table during the initial import versus when running an update. As currently written, the import code produces null-value keys in the `tags` column, while the update code suppresses them. This PR removes that difference and makes the import code use same method that is currently used in the update code. With a test case I've written, the import code produces a tags hstore that looks like this: `"name"=>"OpenMapTiles Secondary 2", "name:de"=>NULL, "name:en"=>NULL, "name_int"=>"OpenMapTiles Secondary 2", "name:latin"=>"OpenMapTiles Secondary 2"` ...while the update code produces a tags hstore that looks like this: `"name"=>"OpenMapTiles Secondary 2", "name_int"=>"OpenMapTiles Secondary 2", "name:latin"=>"OpenMapTiles Secondary 2"` Note the missing NULL values. This bug causes a small amount of space wastage after an update is run, because the update matching code detects the `tags` value as different, resulting in a duplicate copy of the tags value if that row is updated. This causes duplicate objects and breaks GROUP BY clauses that expect to group same-tagged features together. I've tested this by inspection of a generated mbtiles, database spot checks, and the unit test code included in this PR.
2021-11-25 09:45:11 +00:00
transportation_name_tags(hl.geometry, hl.tags, hl.name, hl.name_en, hl.name_de) AS tags,
rm1.network_type,
CASE
WHEN rm1.network_type IS NOT NULL AND rm1.ref::text <> ''
THEN rm1.ref::text
ELSE NULLIF(hl.ref, '')
END AS ref,
hl.highway,
NULLIF(hl.construction, '') AS subclass,
brunnel(hl.is_bridge, hl.is_tunnel, hl.is_ford) AS brunnel,
sac_scale,
CASE WHEN highway IN ('footway', 'steps') THEN layer END AS layer,
CASE WHEN highway IN ('footway', 'steps') THEN level END AS level,
CASE WHEN highway IN ('footway', 'steps') THEN indoor END AS indoor,
NULLIF(rm1.network, '') || '=' || COALESCE(rm1.ref, '') AS route_1,
NULLIF(rm2.network, '') || '=' || COALESCE(rm2.ref, '') AS route_2,
NULLIF(rm3.network, '') || '=' || COALESCE(rm3.ref, '') AS route_3,
NULLIF(rm4.network, '') || '=' || COALESCE(rm4.ref, '') AS route_4,
NULLIF(rm5.network, '') || '=' || COALESCE(rm5.ref, '') AS route_5,
NULLIF(rm6.network, '') || '=' || COALESCE(rm6.ref, '') AS route_6,
hl.z_order,
LEAST(rm1.rank, rm2.rank, rm3.rank, rm4.rank, rm5.rank, rm6.rank) AS route_rank
FROM osm_highway_linestring hl
LEFT OUTER JOIN osm_route_member rm1 ON rm1.member = hl.osm_id AND rm1.concurrency_index=1
LEFT OUTER JOIN osm_route_member rm2 ON rm2.member = hl.osm_id AND rm2.concurrency_index=2
LEFT OUTER JOIN osm_route_member rm3 ON rm3.member = hl.osm_id AND rm3.concurrency_index=3
LEFT OUTER JOIN osm_route_member rm4 ON rm4.member = hl.osm_id AND rm4.concurrency_index=4
LEFT OUTER JOIN osm_route_member rm5 ON rm5.member = hl.osm_id AND rm5.concurrency_index=5
LEFT OUTER JOIN osm_route_member rm6 ON rm6.member = hl.osm_id AND rm6.concurrency_index=6
WHERE (hl.name <> '' OR hl.ref <> '' OR rm1.ref <> '' OR rm1.network <> '')
AND hl.highway <> ''
) AS t;
CREATE UNIQUE INDEX IF NOT EXISTS osm_transportation_name_network_osm_id_idx ON osm_transportation_name_network (osm_id);
BUGFIX: Fix name-based way fragmentation in transportation_name (#1295) I discovered this bug while investigating issues with the updates process related to #1190 #1292, and #814. The `transportation_name` layer produces slightly different `tags` hstore values in the `osm_transportation_name_linestring` table during the initial import versus when running an update. As currently written, the import code produces null-value keys in the `tags` column, while the update code suppresses them. This PR removes that difference and makes the import code use same method that is currently used in the update code. With a test case I've written, the import code produces a tags hstore that looks like this: `"name"=>"OpenMapTiles Secondary 2", "name:de"=>NULL, "name:en"=>NULL, "name_int"=>"OpenMapTiles Secondary 2", "name:latin"=>"OpenMapTiles Secondary 2"` ...while the update code produces a tags hstore that looks like this: `"name"=>"OpenMapTiles Secondary 2", "name_int"=>"OpenMapTiles Secondary 2", "name:latin"=>"OpenMapTiles Secondary 2"` Note the missing NULL values. This bug causes a small amount of space wastage after an update is run, because the update matching code detects the `tags` value as different, resulting in a duplicate copy of the tags value if that row is updated. This causes duplicate objects and breaks GROUP BY clauses that expect to group same-tagged features together. I've tested this by inspection of a generated mbtiles, database spot checks, and the unit test code included in this PR.
2021-11-25 09:45:11 +00:00
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_name_ref_idx ON osm_transportation_name_network (coalesce(tags->'name', ''), coalesce(ref, ''));
CREATE INDEX IF NOT EXISTS osm_transportation_name_network_geometry_idx ON osm_transportation_name_network USING gist (geometry);
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.
2021-08-13 16:00:33 +00:00
-- 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)
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.
2021-08-13 16:00:33 +00:00
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
(
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.
2021-08-13 16:00:33 +00:00
SELECT (ST_Dump(ST_LineMerge(ST_Collect(geometry)))).geom AS geometry,
NULL::bigint AS osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
expressway,
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.
2021-08-13 16:00:33 +00:00
min(z_order) as z_order,
bicycle,
foot,
horse,
mtb_scale,
sac_scale,
CASE
WHEN access IN ('private', 'no') THEN 'no'
ELSE NULL::text END AS access,
toll,
layer
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.
2021-08-13 16:00:33 +00:00
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, expressway, bicycle, foot, horse, mtb_scale, sac_scale, access, toll, 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
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z10 AS
(
SELECT ST_Simplify(geometry, ZRes(12)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
expressway,
z_order,
bicycle,
foot,
horse,
mtb_scale,
sac_scale,
access,
toll,
layer
FROM osm_transportation_merge_linestring_gen_z11
WHERE highway NOT IN ('tertiary', 'tertiary_link', 'busway')
AND construction NOT IN ('tertiary', 'tertiary_link', 'busway')
) /* 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
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z9 AS
(
SELECT ST_Simplify(geometry, ZRes(11)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
expressway,
z_order,
bicycle,
foot,
horse,
mtb_scale,
sac_scale,
access,
toll,
layer
FROM osm_transportation_merge_linestring_gen_z10
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.
2021-08-13 16:00:33 +00:00
-- 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);
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.
2021-08-13 16:00:33 +00:00
-- etldoc: osm_transportation_merge_linestring_gen_z9 -> osm_transportation_merge_linestring_gen_z8
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z8 AS
(
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.
2021-08-13 16:00:33 +00:00
SELECT ST_Simplify(ST_LineMerge(ST_Collect(geometry)), ZRes(10)) AS geometry,
NULL::bigint AS osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
expressway,
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.
2021-08-13 16:00:33 +00:00
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)
AND access IS NULL
GROUP BY highway, network, construction, is_bridge, is_tunnel, is_ford, expressway
) /* 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
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z7 AS
(
SELECT ST_Simplify(geometry, ZRes(9)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
expressway,
z_order
FROM osm_transportation_merge_linestring_gen_z8
Remove useless WHERE clauses from the transportation layer (#1168) This PR removes several redundant/unnecessary WHERE clauses from the transportation layer. Specifically: The table `osm_transportation_merge_linestring` is a view of `osm_highway_linestring` which exposes only motorway/trunk/primary roads: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L122-L123 However, the create statement for the table `osm_transportation_merge_linestring_gen_z8`, which is a view of `osm_transportation_merge_linestring`, also contains a `WHERE` clause which selects down to motorway/trunk/primary roads. This `WHERE` is unnecessary: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L144-L145 This unneeded `WHERE` clause is similarly present in the create statement for `osm_transportation_merge_linestring_gen_z7`, which is a view of `osm_transportation_merge_linestring_gen_z8`: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L163-L164 Likewise, there is a similar redundant `WHERE` clause in the `osm_transportation_merge_linestring_gen_z5` and `osm_transportation_merge_linestring_gen_z6` tables, both of which select down to `motorway` and `trunk`. This `WHERE` clause is only needed on the z6 table, and is redundant on the z5 table. I am not sure what the performance penalty is for these redundant `WHERE` clauses, but there does not appear to be any reason to keep them, and they may incur a performance cost.
2021-08-10 15:55:16 +00:00
-- Current view: motorway/trunk/primary
WHERE ST_Length(geometry) > 50
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z7_geometry_idx
ON osm_transportation_merge_linestring_gen_z7 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z7 -> osm_transportation_merge_linestring_gen_z6
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z6 AS
(
SELECT ST_Simplify(geometry, ZRes(8)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
z_order
FROM osm_transportation_merge_linestring_gen_z7
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.
2021-08-13 16:00:33 +00:00
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
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z5 AS
(
SELECT ST_Simplify(geometry, ZRes(7)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
z_order
FROM osm_transportation_merge_linestring_gen_z6
Remove useless WHERE clauses from the transportation layer (#1168) This PR removes several redundant/unnecessary WHERE clauses from the transportation layer. Specifically: The table `osm_transportation_merge_linestring` is a view of `osm_highway_linestring` which exposes only motorway/trunk/primary roads: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L122-L123 However, the create statement for the table `osm_transportation_merge_linestring_gen_z8`, which is a view of `osm_transportation_merge_linestring`, also contains a `WHERE` clause which selects down to motorway/trunk/primary roads. This `WHERE` is unnecessary: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L144-L145 This unneeded `WHERE` clause is similarly present in the create statement for `osm_transportation_merge_linestring_gen_z7`, which is a view of `osm_transportation_merge_linestring_gen_z8`: https://github.com/openmaptiles/openmaptiles/blob/9e4be3e3b03c26fcc1e63ee4976f44a5d1f8dba1/layers/transportation/update_transportation_merge.sql#L163-L164 Likewise, there is a similar redundant `WHERE` clause in the `osm_transportation_merge_linestring_gen_z5` and `osm_transportation_merge_linestring_gen_z6` tables, both of which select down to `motorway` and `trunk`. This `WHERE` clause is only needed on the z6 table, and is redundant on the z5 table. I am not sure what the performance penalty is for these redundant `WHERE` clauses, but there does not appear to be any reason to keep them, and they may incur a performance cost.
2021-08-10 15:55:16 +00:00
WHERE ST_Length(geometry) > 500
-- Current view: motorway/trunk
) /* DELAY_MATERIALIZED_VIEW_CREATION */;
CREATE INDEX IF NOT EXISTS osm_transportation_merge_linestring_gen_z5_geometry_idx
ON osm_transportation_merge_linestring_gen_z5 USING gist (geometry);
-- etldoc: osm_transportation_merge_linestring_gen_z5 -> osm_transportation_merge_linestring_gen_z4
CREATE MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z4 AS
(
SELECT ST_Simplify(geometry, ZRes(6)) AS geometry,
osm_id,
highway,
network,
construction,
is_bridge,
is_tunnel,
is_ford,
z_order
FROM osm_transportation_merge_linestring_gen_z5
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.
2021-08-13 16:00:33 +00:00
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
ON osm_transportation_merge_linestring_gen_z4 USING gist (geometry);
-- Handle updates
CREATE SCHEMA IF NOT EXISTS transportation;
CREATE TABLE IF NOT EXISTS transportation.updates
(
id serial PRIMARY KEY,
t text,
UNIQUE (t)
);
CREATE OR REPLACE FUNCTION transportation.flag() RETURNS trigger AS
$$
BEGIN
INSERT INTO transportation.updates(t) VALUES ('y') ON CONFLICT(t) DO NOTHING;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION transportation.refresh() RETURNS trigger AS
$$
DECLARE
t TIMESTAMP WITH TIME ZONE := clock_timestamp();
BEGIN
RAISE LOG 'Refresh transportation';
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.
2021-08-13 16:00:33 +00:00
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;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z5;
REFRESH MATERIALIZED VIEW osm_transportation_merge_linestring_gen_z4;
-- noinspection SqlWithoutWhere
DELETE FROM transportation.updates;
RAISE LOG 'Refresh transportation done in %', age(clock_timestamp(), t);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER trigger_flag_transportation
AFTER INSERT OR UPDATE OR DELETE
ON osm_highway_linestring
FOR EACH STATEMENT
EXECUTE PROCEDURE transportation.flag();
CREATE CONSTRAINT TRIGGER trigger_refresh
AFTER INSERT
ON transportation.updates
INITIALLY DEFERRED
FOR EACH ROW
EXECUTE PROCEDURE transportation.refresh();