openmaptiles/layers/water/water.sql

633 wiersze
18 KiB
MySQL

CREATE OR REPLACE FUNCTION water_class(waterway text, water text, leisure text) RETURNS text AS
$$
SELECT CASE
WHEN water IN ('river', 'canal', 'stream', 'ditch', 'drain') THEN 'river'
%%FIELD_MAPPING: class %%
ELSE 'lake'
END;
$$ LANGUAGE SQL IMMUTABLE
PARALLEL SAFE;
2016-10-28 14:53:29 +00:00
CREATE OR REPLACE FUNCTION waterway_brunnel(is_bridge bool, is_tunnel bool) RETURNS text AS
Parallel capability to layer functions (#728) This PR allows queries to be parallelized on recent versions of Postgres. The `PARALLEL SAFE` modifier has been added to the layer functions and a PLPGSQL function to convert strings into number has been replaced. `PARALLEL SAFE` is a modifier for `CREATE FUNCTION` available since Postgres 9.6, so this change does not break current OpenMapTiles supported database version. More details about this topic [here](https://www.postgresql.org/docs/current/parallel-safety.html) and at the reference documentation for [`CREATE FUNCTION`](https://www.postgresql.org/docs/current/sql-createfunction.html). ### Testing procedure The procedure to test this was: * Imported `spain.pbf` in a clean environment * Dumped the OpenMapTiles database from the Postgres Docker image * Created a clean Postgres 12 database using the default Docker image * Installed `postgis` 3 from the default Debian package and `osml10n` 2.5.8 from the repository (`make`, etc.) * Restored the dump * Lowered the postgres planner parameters for triggering parallel plans: ```sql set parallel_setup_cost = 5; set parallel_tuple_cost = 0.005; ``` * Manually added the `PARALLEL SAFE` modifier to each function involved in layer queries (not on updates or inserting functions). * For each layer, run a testing query to confirm parallel workers were created, something like this: ```sql explain analyze select * from layer_aerodrome_label(tilebbox(8,128,95),10,null) union all select * from layer_aerodrome_label(tilebbox(8,128,97),10,null); ``` * After all the layers were processed and confirmed to start parallel executions, a more complete example was run. This example just retrieves the geometries for all the layers from the same tile but without using any MVT related function. <details><summary>Testing query</summary> ```sql -- Using the function layer_landuse explain analyze select geometry from layer_water(tilebbox(14,8020,6178),14) union all select geometry from layer_waterway(tilebbox(14,8020,6178),14) union all select geometry from layer_landcover(tilebbox(14,8020,6178),14) union all select geometry from layer_landuse(tilebbox(14,8020,6178),14) union all select geometry from layer_mountain_peak(tilebbox(14,8020,6178),14) union all select geometry from layer_park(tilebbox(14,8020,6178),14) union all select geometry from layer_boundary(tilebbox(14,8020,6178),14) union all select geometry from layer_aeroway(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation(tilebbox(14,8020,6178),14) union all select geometry from layer_building(tilebbox(14,8020,6178),14) union all select geometry from layer_water_name(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation_name(tilebbox(14,8020,6178),14) union all select geometry from layer_place(tilebbox(14,8020,6178),14) union all select geometry from layer_housenumber(tilebbox(14,8020,6178),14) union all select geometry from layer_poi(tilebbox(14,8020,6178),14) union all select geometry from layer_aerodrome_label(tilebbox(14,8020,6178),14); ``` </details> You can inspect the execution plan and results on [this page](https://explain.dalibo.com/plan/3z). Also [attaching](https://github.com/openmaptiles/openmaptiles/files/3951822/explain-tile-simple.tar.gz) the query and JSON output for future reference. The website gives a ton of details, but you may want to search for nodes mentioning `workers` or `parallel` like in this area referring to `osm_border` or `osm_aeroway_linestring` entities ![image](https://user-images.githubusercontent.com/188264/70647153-9cac9300-1c48-11ea-96ea-ac7a1e2f4a79.png) ### Next steps Since the execution plan is not showing a parallel append at the top level, meaning it's not running each layer individually, I want to continue experimenting with parameters and queries to see if it's possible to even parallelize more the request. I will post my finding here, even no change in the code should happen. cc. @nyurik Co-authored-by: Yuri Astrakhan <yuriastrakhan@gmail.com>
2020-02-01 00:36:02 +00:00
$$
SELECT CASE
WHEN is_bridge THEN 'bridge'
WHEN is_tunnel THEN 'tunnel'
END;
$$ LANGUAGE SQL IMMUTABLE
STRICT
PARALLEL SAFE;
-- Get matching osm id for natural earth id.
DROP MATERIALIZED VIEW IF EXISTS match_osm_ne_id CASCADE;
CREATE MATERIALIZED VIEW match_osm_ne_id AS
(
WITH name_match AS
(
-- Distinct on keeps just the first occurence -> order by 'area_ratio DESC'.
SELECT DISTINCT ON (ne.ne_id)
ne.ne_id,
osm.osm_id,
(ST_Area(ST_Intersection(ne.geometry, osm.geometry))/ST_Area(ne.geometry)) AS area_ratio
FROM ne_10m_lakes ne, osm_water_polygon_gen_z6 osm
WHERE ne.name = osm.name
AND ST_Intersects(ne.geometry, osm.geometry)
ORDER BY ne_id,
area_ratio DESC
),
-- Add lakes which are not match by name, but intersects.
-- Duplicity solves 'DISTICT ON' with 'area_ratio'.
geom_match AS
(SELECT DISTINCT ON (ne.ne_id)
ne.ne_id,
osm.osm_id,
(ST_Area(ST_Intersection(ne.geometry, osm.geometry))/ST_Area(ne.geometry)) AS area_ratio
FROM ne_10m_lakes ne, osm_water_polygon_gen_z6 osm
WHERE ST_Intersects(ne.geometry, osm.geometry)
AND ne.ne_id NOT IN
( SELECT ne_id
FROM name_match
)
ORDER BY ne_id,
area_ratio DESC
)
SELECT ne_id,
osm_id
FROM name_match
UNION
SELECT ne_id,
osm_id
FROM geom_match
);
-- ne_10m_ocean
-- etldoc: ne_10m_ocean -> ne_10m_ocean_gen_z5
DROP MATERIALIZED VIEW IF EXISTS ne_10m_ocean_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_ocean_gen_z5 AS
(
SELECT NULL::integer AS id,
(ST_Dump(ST_Simplify(geometry, ZRes(7)))).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_10m_ocean
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_ocean_gen_z5_idx ON ne_10m_ocean_gen_z5 USING gist (geometry);
-- ne_10m_lakes
-- etldoc: ne_10m_lakes -> ne_10m_lakes_gen_z5
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z5 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z5 AS
(
SELECT COALESCE(osm.osm_id, ne_id) AS id,
-- Union fixing e.g. Lake Huron and Georgian Bay duplicity
(ST_Dump(ST_MakeValid(ST_Simplify(ST_Union(geometry), ZRes(7))))).geom AS geometry,
'lake'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_10m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
GROUP BY COALESCE(osm.osm_id, ne_id), is_intermittent, is_bridge, is_tunnel
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z5_idx ON ne_10m_lakes_gen_z5 USING gist (geometry);
-- etldoc: ne_10m_lakes_gen_z5 -> ne_10m_lakes_gen_z4
DROP MATERIALIZED VIEW IF EXISTS ne_10m_lakes_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_10m_lakes_gen_z4 AS
(
SELECT id,
(ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(6))))).geom AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_10m_lakes_gen_z5
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_10m_lakes_gen_z4_idx ON ne_10m_lakes_gen_z4 USING gist (geometry);
-- ne_50m_ocean
-- etldoc: ne_50m_ocean -> ne_50m_ocean_gen_z4
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z4 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z4 AS
(
SELECT NULL::integer AS id,
(ST_Dump(ST_Simplify(geometry, ZRes(6)))).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_50m_ocean
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z4_idx ON ne_50m_ocean_gen_z4 USING gist (geometry);
-- etldoc: ne_50m_ocean_gen_z4 -> ne_50m_ocean_gen_z3
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z3 AS
(
SELECT id,
ST_Simplify(geometry, ZRes(5)) AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_ocean_gen_z4
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z3_idx ON ne_50m_ocean_gen_z3 USING gist (geometry);
-- etldoc: ne_50m_ocean_gen_z3 -> ne_50m_ocean_gen_z2
DROP MATERIALIZED VIEW IF EXISTS ne_50m_ocean_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_ocean_gen_z2 AS
(
SELECT id,
ST_Simplify(geometry, ZRes(4)) AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_ocean_gen_z3
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_ocean_gen_z2_idx ON ne_50m_ocean_gen_z2 USING gist (geometry);
-- ne_50m_lakes
-- etldoc: ne_50m_lakes -> ne_50m_lakes_gen_z3
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z3 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z3 AS
(
SELECT COALESCE(osm.osm_id, ne_id) AS id,
(ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(5))))).geom AS geometry,
'lake'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_50m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z3_idx ON ne_50m_lakes_gen_z3 USING gist (geometry);
-- etldoc: ne_50m_lakes_gen_z3 -> ne_50m_lakes_gen_z2
DROP MATERIALIZED VIEW IF EXISTS ne_50m_lakes_gen_z2 CASCADE;
CREATE MATERIALIZED VIEW ne_50m_lakes_gen_z2 AS
(
SELECT id,
(ST_Dump(ST_MakeValid(ST_Simplify(geometry, ZRes(4))))).geom AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_lakes_gen_z3
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_50m_lakes_gen_z2_idx ON ne_50m_lakes_gen_z2 USING gist (geometry);
--ne_110m_ocean
-- etldoc: ne_110m_ocean -> ne_110m_ocean_gen_z1
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z1 AS
(
SELECT NULL::integer AS id,
ST_Simplify(geometry, ZRes(3)) AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_110m_ocean
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z1_idx ON ne_110m_ocean_gen_z1 USING gist (geometry);
-- etldoc: ne_110m_ocean_gen_z1 -> ne_110m_ocean_gen_z0
DROP MATERIALIZED VIEW IF EXISTS ne_110m_ocean_gen_z0 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_ocean_gen_z0 AS
(
SELECT id,
ST_Simplify(geometry, ZRes(2)) AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_ocean_gen_z1
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_ocean_gen_z0_idx ON ne_110m_ocean_gen_z0 USING gist (geometry);
-- ne_110m_lakes
-- etldoc: ne_110m_lakes -> ne_110m_lakes_gen_z1
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z1 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z1 AS
(
SELECT COALESCE(osm.osm_id, ne_id) AS id,
(ST_Dump(ST_Simplify(geometry, ZRes(3)))).geom AS geometry,
'lake'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM ne_110m_lakes
LEFT JOIN match_osm_ne_id osm USING (ne_id)
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z1_idx ON ne_110m_lakes_gen_z1 USING gist (geometry);
-- etldoc: ne_110m_lakes_gen_z1 -> ne_110m_lakes_gen_z0
DROP MATERIALIZED VIEW IF EXISTS ne_110m_lakes_gen_z0 CASCADE;
CREATE MATERIALIZED VIEW ne_110m_lakes_gen_z0 AS
(
SELECT id,
(ST_Dump(ST_Simplify(geometry, ZRes(2)))).geom AS geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_lakes_gen_z1
) /* DELAY_MATERIALIZED_VIEW_CREATION */ ;
CREATE INDEX IF NOT EXISTS ne_110m_lakes_gen_z0_idx ON ne_110m_lakes_gen_z0 USING gist (geometry);
DROP MATERIALIZED VIEW IF EXISTS water_z6;
DROP MATERIALIZED VIEW IF EXISTS water_z7;
DROP MATERIALIZED VIEW IF EXISTS water_z8;
DROP MATERIALIZED VIEW IF EXISTS water_z9;
DROP MATERIALIZED VIEW IF EXISTS water_z10;
DROP MATERIALIZED VIEW IF EXISTS water_z11;
DROP MATERIALIZED VIEW IF EXISTS water_z12;
CREATE OR REPLACE VIEW water_z0 AS
(
-- etldoc: ne_110m_ocean_gen_z0 -> water_z0
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_ocean_gen_z0
UNION ALL
-- etldoc: ne_110m_lakes_gen_z0 -> water_z0
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_lakes_gen_z0
);
CREATE OR REPLACE VIEW water_z1 AS
(
-- etldoc: ne_110m_ocean_gen_z1 -> water_z1
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_ocean_gen_z1
UNION ALL
-- etldoc: ne_110m_lakes_gen_z1 -> water_z1
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_110m_lakes_gen_z1
);
CREATE OR REPLACE VIEW water_z2 AS
(
-- etldoc: ne_50m_ocean_gen_z2 -> water_z2
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_ocean_gen_z2
UNION ALL
-- etldoc: ne_50m_lakes_gen_z2 -> water_z2
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_lakes_gen_z2
);
CREATE OR REPLACE VIEW water_z3 AS
(
-- etldoc: ne_50m_ocean_gen_z3 -> water_z3
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_ocean_gen_z3
UNION ALL
-- etldoc: ne_50m_lakes_gen_z3 -> water_z3
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_lakes_gen_z3
);
CREATE OR REPLACE VIEW water_z4 AS
(
-- etldoc: ne_50m_ocean_gen_z4 -> water_z4
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_50m_ocean_gen_z4
UNION ALL
-- etldoc: ne_10m_lakes_gen_z4 -> water_z4
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_10m_lakes_gen_z4
);
CREATE OR REPLACE VIEW water_z5 AS
(
-- etldoc: ne_10m_ocean_gen_z5 -> water_z5
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_10m_ocean_gen_z5
UNION ALL
-- etldoc: ne_10m_lakes_gen_z5 -> water_z5
SELECT id,
geometry,
class,
is_intermittent,
is_bridge,
is_tunnel
FROM ne_10m_lakes_gen_z5
);
CREATE MATERIALIZED VIEW water_z6 AS
(
-- etldoc: osm_ocean_polygon_gen_z6 -> water_z6
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z6
UNION ALL
-- etldoc: osm_water_polygon_gen_z6 -> water_z6
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z6
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z6 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z7 AS
(
-- etldoc: osm_ocean_polygon_gen_z7 -> water_z7
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z7
UNION ALL
-- etldoc: osm_water_polygon_gen_z7 -> water_z7
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z7
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z7 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z8 AS
(
-- etldoc: osm_ocean_polygon_gen_z8 -> water_z8
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z8
UNION ALL
-- etldoc: osm_water_polygon_gen_z8 -> water_z8
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z8
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z8 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z9 AS
(
-- etldoc: osm_ocean_polygon_gen_z9 -> water_z9
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z9
UNION ALL
-- etldoc: osm_water_polygon_gen_z9 -> water_z9
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z9
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z9 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z10 AS
(
-- etldoc: osm_ocean_polygon_gen_z10 -> water_z10
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z10
UNION ALL
-- etldoc: osm_water_polygon_gen_z10 -> water_z10
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z10
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z10 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z11 AS
(
-- etldoc: osm_ocean_polygon_gen_z11 -> water_z11
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_gen_z11
UNION ALL
-- etldoc: osm_water_polygon_gen_z11 -> water_z11
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_water_polygon_gen_z11
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z11 USING gist(geometry);
CREATE MATERIALIZED VIEW water_z12 AS
(
-- etldoc: osm_ocean_polygon_union -> water_z12
SELECT NULL::integer AS id,
(ST_Dump(geometry)).geom AS geometry,
'ocean'::text AS class,
NULL::boolean AS is_intermittent,
NULL::boolean AS is_bridge,
NULL::boolean AS is_tunnel
FROM osm_ocean_polygon_union
UNION ALL
-- etldoc: osm_water_polygon -> water_z12
SELECT osm_id AS id,
(ST_Dump(geometry)).geom AS geometry,
water_class(waterway, water, leisure) AS class,
is_intermittent,
is_bridge,
is_tunnel
FROM osm_water_polygon
WHERE "natural" != 'bay'
);
CREATE INDEX ON water_z12 USING gist(geometry);
-- etldoc: layer_water [shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_water |<z0> z0|<z1>z1|<z2>z2|<z3>z3 |<z4> z4|<z5>z5|<z6>z6|<z7>z7| <z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12+" ] ;
2016-11-10 13:08:39 +00:00
CREATE OR REPLACE FUNCTION layer_water(bbox geometry, zoom_level int)
RETURNS TABLE
(
id bigint,
geometry geometry,
class text,
brunnel text,
intermittent int
)
AS
Parallel capability to layer functions (#728) This PR allows queries to be parallelized on recent versions of Postgres. The `PARALLEL SAFE` modifier has been added to the layer functions and a PLPGSQL function to convert strings into number has been replaced. `PARALLEL SAFE` is a modifier for `CREATE FUNCTION` available since Postgres 9.6, so this change does not break current OpenMapTiles supported database version. More details about this topic [here](https://www.postgresql.org/docs/current/parallel-safety.html) and at the reference documentation for [`CREATE FUNCTION`](https://www.postgresql.org/docs/current/sql-createfunction.html). ### Testing procedure The procedure to test this was: * Imported `spain.pbf` in a clean environment * Dumped the OpenMapTiles database from the Postgres Docker image * Created a clean Postgres 12 database using the default Docker image * Installed `postgis` 3 from the default Debian package and `osml10n` 2.5.8 from the repository (`make`, etc.) * Restored the dump * Lowered the postgres planner parameters for triggering parallel plans: ```sql set parallel_setup_cost = 5; set parallel_tuple_cost = 0.005; ``` * Manually added the `PARALLEL SAFE` modifier to each function involved in layer queries (not on updates or inserting functions). * For each layer, run a testing query to confirm parallel workers were created, something like this: ```sql explain analyze select * from layer_aerodrome_label(tilebbox(8,128,95),10,null) union all select * from layer_aerodrome_label(tilebbox(8,128,97),10,null); ``` * After all the layers were processed and confirmed to start parallel executions, a more complete example was run. This example just retrieves the geometries for all the layers from the same tile but without using any MVT related function. <details><summary>Testing query</summary> ```sql -- Using the function layer_landuse explain analyze select geometry from layer_water(tilebbox(14,8020,6178),14) union all select geometry from layer_waterway(tilebbox(14,8020,6178),14) union all select geometry from layer_landcover(tilebbox(14,8020,6178),14) union all select geometry from layer_landuse(tilebbox(14,8020,6178),14) union all select geometry from layer_mountain_peak(tilebbox(14,8020,6178),14) union all select geometry from layer_park(tilebbox(14,8020,6178),14) union all select geometry from layer_boundary(tilebbox(14,8020,6178),14) union all select geometry from layer_aeroway(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation(tilebbox(14,8020,6178),14) union all select geometry from layer_building(tilebbox(14,8020,6178),14) union all select geometry from layer_water_name(tilebbox(14,8020,6178),14) union all select geometry from layer_transportation_name(tilebbox(14,8020,6178),14) union all select geometry from layer_place(tilebbox(14,8020,6178),14) union all select geometry from layer_housenumber(tilebbox(14,8020,6178),14) union all select geometry from layer_poi(tilebbox(14,8020,6178),14) union all select geometry from layer_aerodrome_label(tilebbox(14,8020,6178),14); ``` </details> You can inspect the execution plan and results on [this page](https://explain.dalibo.com/plan/3z). Also [attaching](https://github.com/openmaptiles/openmaptiles/files/3951822/explain-tile-simple.tar.gz) the query and JSON output for future reference. The website gives a ton of details, but you may want to search for nodes mentioning `workers` or `parallel` like in this area referring to `osm_border` or `osm_aeroway_linestring` entities ![image](https://user-images.githubusercontent.com/188264/70647153-9cac9300-1c48-11ea-96ea-ac7a1e2f4a79.png) ### Next steps Since the execution plan is not showing a parallel append at the top level, meaning it's not running each layer individually, I want to continue experimenting with parameters and queries to see if it's possible to even parallelize more the request. I will post my finding here, even no change in the code should happen. cc. @nyurik Co-authored-by: Yuri Astrakhan <yuriastrakhan@gmail.com>
2020-02-01 00:36:02 +00:00
$$
SELECT id,
geometry,
class::text,
waterway_brunnel(is_bridge, is_tunnel) AS brunnel,
is_intermittent::int AS intermittent
FROM (
-- etldoc: water_z0 -> layer_water:z0
SELECT *
FROM water_z0
WHERE zoom_level = 0
UNION ALL
-- etldoc: water_z1 -> layer_water:z1
SELECT *
FROM water_z1
WHERE zoom_level = 1
UNION ALL
-- etldoc: water_z2 -> layer_water:z2
SELECT *
FROM water_z2
WHERE zoom_level = 2
UNION ALL
-- etldoc: water_z3 -> layer_water:z3
SELECT *
FROM water_z3
WHERE zoom_level = 3
UNION ALL
-- etldoc: water_z4 -> layer_water:z4
SELECT *
FROM water_z4
WHERE zoom_level = 4
UNION ALL
-- etldoc: water_z5 -> layer_water:z5
SELECT *
FROM water_z5
WHERE zoom_level = 5
UNION ALL
-- etldoc: water_z6 -> layer_water:z6
SELECT *
FROM water_z6
WHERE zoom_level = 6
UNION ALL
-- etldoc: water_z7 -> layer_water:z7
SELECT *
FROM water_z7
WHERE zoom_level = 7
UNION ALL
-- etldoc: water_z8 -> layer_water:z8
SELECT *
FROM water_z8
WHERE zoom_level = 8
UNION ALL
-- etldoc: water_z9 -> layer_water:z9
SELECT *
FROM water_z9
WHERE zoom_level = 9
UNION ALL
-- etldoc: water_z10 -> layer_water:z10
SELECT *
FROM water_z10
WHERE zoom_level = 10
UNION ALL
-- etldoc: water_z11 -> layer_water:z11
SELECT *
FROM water_z11
WHERE zoom_level = 11
UNION ALL
-- etldoc: water_z12 -> layer_water:z12
SELECT *
FROM water_z12
WHERE zoom_level >= 12
) AS zoom_levels
WHERE geometry && bbox;
$$ LANGUAGE SQL STABLE
-- STRICT
PARALLEL SAFE;