From 9fa3d4b5a0cd7a9022dc4e448bfcb84cbea15551 Mon Sep 17 00:00:00 2001 From: lukasmartinelli Date: Tue, 25 Oct 2016 14:54:22 +0200 Subject: [PATCH] Add custom types and simplify highway query --- layers/highway/highway.sql | 174 +++++++---------------------- layers/highway/highway.yaml | 4 +- layers/highway/mapping.yaml | 15 ++- layers/highway/ne_global_roads.sql | 23 ++++ layers/highway/types.sql | 31 +++++ 5 files changed, 110 insertions(+), 137 deletions(-) create mode 100644 layers/highway/ne_global_roads.sql create mode 100644 layers/highway/types.sql diff --git a/layers/highway/highway.sql b/layers/highway/highway.sql index e2eebe50..10f6d089 100644 --- a/layers/highway/highway.sql +++ b/layers/highway/highway.sql @@ -1,140 +1,48 @@ -CREATE OR REPLACE FUNCTION highway_brunnel(is_bridge boolean, is_tunnel boolean) RETURNS TEXT AS $$ - SELECT CASE - WHEN is_bridge THEN 'bridge' - WHEN is_tunnel THEN 'tunnel' - ELSE NULL - END; -$$ LANGUAGE SQL IMMUTABLE; - -CREATE OR REPLACE FUNCTION highway_class(highway TEXT) RETURNS TEXT AS $$ - SELECT CASE - WHEN highway IN ('unclassified', 'residential', 'living_street', 'road', 'track', 'service') THEN 'minor' - WHEN highway IN ('primary', 'primary_link') THEN 'primary' - WHEN highway IN ('secondary', 'secondary_link') THEN 'secondary' - WHEN highway IN ('tertiary', 'tertiary_link') THEN 'tertiary' - WHEN highway IN ('motorway', 'motorway_link') THEN 'motorway' - WHEN highway IN ('trunk', 'trunk_link') THEN 'trunk' - WHEN highway IN ('pedestrian', 'path', 'footway', 'cycleway', 'steps') THEN 'path' - ELSE NULL - END; -$$ LANGUAGE SQL IMMUTABLE; - -CREATE OR REPLACE FUNCTION ne_highway(type VARCHAR) RETURNS VARCHAR AS $$ - SELECT CASE type - WHEN 'Major Highway' THEN 'motorway' - WHEN 'Secondary Highway' THEN 'trunk' - WHEN 'Road' THEN 'primary' - ELSE type - END; -$$ LANGUAGE SQL IMMUTABLE; - -CREATE TABLE IF NOT EXISTS ne_10m_global_roads AS ( - SELECT NULL::bigint as osm_id, geom AS geometry, scalerank, ne_highway(type) AS highway, NULL::boolean AS is_tunnel, NULL::boolean AS is_bridge, 0::int as z_order - FROM ne_10m_roads - WHERE continent <> 'North America' - AND featurecla = 'Road' - AND type IN ('Major Highway', 'Secondary Highway', 'Road') - UNION ALL - SELECT NULL::bigint as osm_id, geom AS geometry, scalerank, ne_highway(type) AS highway, NULL::boolean AS is_tunnel, NULL::boolean AS is_bridge, 0::int as z_order - FROM ne_10m_roads_north_america - WHERE type IN ('Major Highway', 'Secondary Highway', 'Road') -); - -CREATE INDEX IF NOT EXISTS ne_10m_global_roads_geometry_idx ON ne_10m_global_roads USING gist(geometry); -CREATE INDEX IF NOT EXISTS ne_10m_global_roads_scalerank_idx ON ne_10m_global_roads(scalerank); - -CREATE OR REPLACE VIEW highway_z4 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM ne_10m_global_roads - WHERE scalerank <= 5 -); - -CREATE OR REPLACE VIEW highway_z5 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM ne_10m_global_roads - WHERE scalerank <= 6 -); - -CREATE OR REPLACE VIEW highway_z6 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM ne_10m_global_roads - WHERE scalerank <= 7 -); - -CREATE OR REPLACE VIEW highway_z8 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring_gen4 -); - -CREATE OR REPLACE VIEW highway_z9 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring_gen3 -); - -CREATE OR REPLACE VIEW highway_z10 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring_gen2 -); - -CREATE OR REPLACE VIEW highway_z11 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring_gen1 -); - -CREATE OR REPLACE VIEW highway_z12 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring - WHERE highway IN ('motorway','trunk','primary', 'secondary', 'tertiary', 'minor') -); - -CREATE OR REPLACE VIEW highway_z13 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring - WHERE highway IN ( - 'motorway', - 'motorway_link', - 'trunk', - 'trunk_link', - 'primary', - 'primary_link', - 'secondary', - 'secondary_link', - 'tertiary', - 'tertiary_link', - 'road', - 'living_street', - 'service', - 'residential' - ) -); - -CREATE OR REPLACE VIEW highway_z14 AS ( - SELECT osm_id, geometry, highway, is_tunnel, is_bridge, z_order - FROM osm_highway_linestring -); +CREATE OR REPLACE FUNCTION highway_is_link(highway TEXT) RETURNS BOOLEAN AS $$ + SELECT highway LIKE '%_link'; +$$ LANGUAGE SQL IMMUTABLE STRICT; CREATE OR REPLACE FUNCTION layer_highway(bbox geometry, zoom_level int) -RETURNS TABLE(osm_id bigint, geometry geometry, class text, subclass text) AS $$ - SELECT osm_id, geometry, highway_class(highway) AS class, highway AS subclass FROM ( - SELECT * FROM highway_z4 WHERE zoom_level BETWEEN 4 AND 5 +RETURNS TABLE(osm_id bigint, geometry geometry, class highway_class, subclass text, properties highway_properties) AS $$ + SELECT + osm_id, geometry, + to_highway_class(highway) AS class, highway AS subclass, + to_highway_properties(is_bridge, is_tunnel, is_ford, is_ramp, is_oneway) AS properties + FROM ( + SELECT + NULL::bigint AS osm_id, geometry, highway, + FALSE AS is_bridge, FALSE AS is_tunnel, FALSE AS is_ford, FALSE AS is_ramp, FALSE AS is_oneway, + 0 AS z_order + FROM ne_10m_global_roads + WHERE zoom_level BETWEEN 4 AND 7 AND scalerank <= 1 + zoom_level + UNION ALL + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring_gen4 + WHERE zoom_level = 8 + UNION ALL + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring_gen3 + WHERE zoom_level = 9 + UNION ALL + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring_gen2 + WHERE zoom_level = 10 + UNION ALL + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring_gen1 + WHERE zoom_level = 11 + UNION ALL + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring + WHERE zoom_level = 12 AND to_highway_class(highway) < 'minor_road'::highway_class AND NOT highway_is_link(highway) UNION ALL - SELECT * FROM highway_z5 WHERE zoom_level = 5 + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring + WHERE zoom_level = 13 AND to_highway_class(highway) < 'path'::highway_class UNION ALL - SELECT * FROM highway_z6 WHERE zoom_level BETWEEN 6 AND 7 - UNION ALL - SELECT * FROM highway_z8 WHERE zoom_level = 8 - UNION ALL - SELECT * FROM highway_z9 WHERE zoom_level = 9 - UNION ALL - SELECT * FROM highway_z10 WHERE zoom_level = 10 - UNION ALL - SELECT * FROM highway_z11 WHERE zoom_level = 11 - UNION ALL - SELECT * FROM highway_z12 WHERE zoom_level = 12 - UNION ALL - SELECT * FROM highway_z13 WHERE zoom_level = 13 - UNION ALL - SELECT * FROM highway_z14 WHERE zoom_level >= 14 + SELECT osm_id, geometry, highway, is_bridge, is_tunnel, is_ford, is_ramp, is_oneway, z_order + FROM osm_highway_linestring + WHERE zoom_level >= 14 ) AS zoom_levels WHERE geometry && bbox ORDER BY z_order ASC; diff --git a/layers/highway/highway.yaml b/layers/highway/highway.yaml index 036847c4..867e306f 100644 --- a/layers/highway/highway.yaml +++ b/layers/highway/highway.yaml @@ -10,8 +10,10 @@ layer: datasource: geometry_field: geometry srid: 900913 - query: (SELECT * FROM layer_highway(!bbox!, z(!scale_denominator!))) AS t + query: (SELECT osm_id, geometry, class::text, subclass, properties::text FROM layer_highway(!bbox!, z(!scale_denominator!))) AS t schema: + - ./types.sql + - ./ne_global_roads.sql - ./highway.sql datasources: - type: imposm3 diff --git a/layers/highway/mapping.yaml b/layers/highway/mapping.yaml index 9430ef17..aa8c02fa 100644 --- a/layers/highway/mapping.yaml +++ b/layers/highway/mapping.yaml @@ -26,9 +26,9 @@ tables: - name: highway key: highway type: string - - key: oneway - name: oneway - type: direction + - key: ref + name: ref + type: string - name: z_order type: wayzorder - key: tunnel @@ -37,6 +37,15 @@ tables: - key: bridge name: is_bridge type: bool + - key: ramp + name: is_ramp + type: bool + - key: ford + name: is_ford + type: bool + - key: oneway + name: is_oneway + type: bool - key: name name: name type: string diff --git a/layers/highway/ne_global_roads.sql b/layers/highway/ne_global_roads.sql new file mode 100644 index 00000000..f52bb0ff --- /dev/null +++ b/layers/highway/ne_global_roads.sql @@ -0,0 +1,23 @@ +CREATE OR REPLACE FUNCTION ne_highway(type VARCHAR) RETURNS VARCHAR AS $$ + SELECT CASE type + WHEN 'Major Highway' THEN 'motorway' + WHEN 'Secondary Highway' THEN 'trunk' + WHEN 'Road' THEN 'primary' + ELSE type + END; +$$ LANGUAGE SQL IMMUTABLE; + +CREATE TABLE IF NOT EXISTS ne_10m_global_roads AS ( + SELECT geom AS geometry, scalerank, ne_highway(type) AS highway + FROM ne_10m_roads + WHERE continent <> 'North America' + AND featurecla = 'Road' + AND type IN ('Major Highway', 'Secondary Highway', 'Road') + UNION ALL + SELECT geom AS geometry, scalerank, ne_highway(type) AS highway + FROM ne_10m_roads_north_america + WHERE type IN ('Major Highway', 'Secondary Highway', 'Road') +); + +CREATE INDEX IF NOT EXISTS ne_10m_global_roads_geometry_idx ON ne_10m_global_roads USING gist(geometry); +CREATE INDEX IF NOT EXISTS ne_10m_global_roads_scalerank_idx ON ne_10m_global_roads(scalerank); diff --git a/layers/highway/types.sql b/layers/highway/types.sql new file mode 100644 index 00000000..92b6bbac --- /dev/null +++ b/layers/highway/types.sql @@ -0,0 +1,31 @@ +DROP TYPE IF EXISTS highway_class CASCADE; +CREATE TYPE highway_class AS ENUM ('motorway', 'trunk', 'primary', 'secondary', 'tertiary', 'minor_road', 'path'); + +DROP TYPE IF EXISTS highway_properties CASCADE; +CREATE TYPE highway_properties AS ENUM ('bridge:oneway', 'tunnel:oneway', 'ramp', 'ford', 'bridge', 'tunnel', 'oneway'); + +CREATE OR REPLACE FUNCTION to_highway_class(highway TEXT) RETURNS highway_class AS $$ + SELECT CASE + WHEN highway IN ('motorway', 'motorway_link') THEN 'motorway'::highway_class + WHEN highway IN ('trunk', 'trunk_link') THEN 'trunk'::highway_class + WHEN highway IN ('primary', 'primary_link') THEN 'primary'::highway_class + WHEN highway IN ('secondary', 'secondary_link') THEN 'secondary'::highway_class + WHEN highway IN ('tertiary', 'tertiary_link') THEN 'tertiary'::highway_class + WHEN highway IN ('unclassified', 'residential', 'living_street', 'road', 'track', 'service') THEN 'minor_road'::highway_class + WHEN highway IN ('pedestrian', 'path', 'footway', 'cycleway', 'steps') THEN 'path'::highway_class + ELSE NULL + END; +$$ LANGUAGE SQL IMMUTABLE STRICT; + +CREATE OR REPLACE FUNCTION to_highway_properties(is_bridge boolean, is_tunnel boolean, is_ford boolean, is_ramp boolean, is_oneway boolean) RETURNS highway_properties AS $$ + SELECT CASE + WHEN is_bridge AND is_oneway THEN 'bridge:oneway'::highway_properties + WHEN is_tunnel AND is_oneway THEN 'tunnel:oneway'::highway_properties + WHEN is_ramp THEN 'ramp'::highway_properties + WHEN is_ford THEN 'ford'::highway_properties + WHEN is_bridge THEN 'bridge'::highway_properties + WHEN is_tunnel THEN 'tunnel'::highway_properties + WHEN is_oneway THEN 'oneway'::highway_properties + ELSE NULL + END; +$$ LANGUAGE SQL IMMUTABLE STRICT;