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  ### 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>
113 lines
5.1 KiB
PL/PgSQL
113 lines
5.1 KiB
PL/PgSQL
CREATE OR REPLACE FUNCTION waterway_brunnel(is_bridge BOOL, is_tunnel BOOL) RETURNS TEXT AS $$
|
|
SELECT CASE
|
|
WHEN is_bridge THEN 'bridge'
|
|
WHEN is_tunnel THEN 'tunnel'
|
|
END;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE STRICT PARALLEL SAFE;
|
|
|
|
-- etldoc: ne_110m_rivers_lake_centerlines -> waterway_z3
|
|
CREATE OR REPLACE VIEW waterway_z3 AS (
|
|
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en, NULL::text AS name_de, NULL::hstore AS tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM ne_110m_rivers_lake_centerlines
|
|
WHERE featurecla = 'River'
|
|
);
|
|
|
|
-- etldoc: ne_50m_rivers_lake_centerlines -> waterway_z4
|
|
CREATE OR REPLACE VIEW waterway_z4 AS (
|
|
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en, NULL::text AS name_de, NULL::hstore AS tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM ne_50m_rivers_lake_centerlines
|
|
WHERE featurecla = 'River'
|
|
);
|
|
|
|
-- etldoc: ne_10m_rivers_lake_centerlines -> waterway_z6
|
|
CREATE OR REPLACE VIEW waterway_z6 AS (
|
|
SELECT geometry, 'river'::text AS class, NULL::text AS name, NULL::text AS name_en, NULL::text AS name_de, NULL::hstore AS tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM ne_10m_rivers_lake_centerlines
|
|
WHERE featurecla = 'River'
|
|
);
|
|
|
|
-- etldoc: osm_important_waterway_linestring_gen3 -> waterway_z9
|
|
CREATE OR REPLACE VIEW waterway_z9 AS (
|
|
SELECT geometry, 'river'::text AS class, name, name_en, name_de, tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM osm_important_waterway_linestring_gen3
|
|
);
|
|
|
|
-- etldoc: osm_important_waterway_linestring_gen2 -> waterway_z10
|
|
CREATE OR REPLACE VIEW waterway_z10 AS (
|
|
SELECT geometry, 'river'::text AS class, name, name_en, name_de, tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM osm_important_waterway_linestring_gen2
|
|
);
|
|
|
|
-- etldoc:osm_important_waterway_linestring_gen1 -> waterway_z11
|
|
CREATE OR REPLACE VIEW waterway_z11 AS (
|
|
SELECT geometry, 'river'::text AS class, name, name_en, name_de, tags, NULL::boolean AS is_bridge, NULL::boolean AS is_tunnel, NULL::boolean AS is_intermittent
|
|
FROM osm_important_waterway_linestring_gen1
|
|
);
|
|
|
|
-- etldoc: osm_waterway_linestring -> waterway_z12
|
|
CREATE OR REPLACE VIEW waterway_z12 AS (
|
|
SELECT geometry, waterway::text AS class, name, name_en, name_de, tags, is_bridge, is_tunnel, is_intermittent
|
|
FROM osm_waterway_linestring
|
|
WHERE waterway IN ('river', 'canal')
|
|
);
|
|
|
|
-- etldoc: osm_waterway_linestring -> waterway_z13
|
|
CREATE OR REPLACE VIEW waterway_z13 AS (
|
|
SELECT geometry, waterway::text AS class, name, name_en, name_de, tags, is_bridge, is_tunnel, is_intermittent
|
|
FROM osm_waterway_linestring
|
|
WHERE waterway IN ('river', 'canal', 'stream', 'drain', 'ditch')
|
|
);
|
|
|
|
-- etldoc: osm_waterway_linestring -> waterway_z14
|
|
CREATE OR REPLACE VIEW waterway_z14 AS (
|
|
SELECT geometry, waterway::text AS class, name, name_en, name_de, tags, is_bridge, is_tunnel, is_intermittent
|
|
FROM osm_waterway_linestring
|
|
);
|
|
|
|
-- etldoc: layer_waterway[shape=record fillcolor=lightpink, style="rounded,filled",
|
|
-- etldoc: label="layer_waterway | <z3> z3 |<z4_5> z4-z5 |<z6_8> z6-8 | <z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14> z14+" ];
|
|
|
|
CREATE OR REPLACE FUNCTION layer_waterway(bbox geometry, zoom_level int)
|
|
RETURNS TABLE(geometry geometry, class text, name text, name_en text, name_de text, brunnel text, intermittent int, tags hstore) AS $$
|
|
SELECT geometry, class,
|
|
NULLIF(name, '') AS name,
|
|
COALESCE(NULLIF(name_en, ''), name) AS name_en,
|
|
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
|
|
waterway_brunnel(is_bridge, is_tunnel) AS brunnel,
|
|
is_intermittent::int AS intermittent,
|
|
tags
|
|
FROM (
|
|
-- etldoc: waterway_z3 -> layer_waterway:z3
|
|
SELECT * FROM waterway_z3 WHERE zoom_level = 3
|
|
UNION ALL
|
|
-- etldoc: waterway_z4 -> layer_waterway:z4_5
|
|
SELECT * FROM waterway_z4 WHERE zoom_level BETWEEN 4 AND 5
|
|
UNION ALL
|
|
-- etldoc: waterway_z6 -> layer_waterway:z6_8
|
|
SELECT * FROM waterway_z6 WHERE zoom_level BETWEEN 6 AND 8
|
|
UNION ALL
|
|
-- etldoc: waterway_z9 -> layer_waterway:z9
|
|
SELECT * FROM waterway_z9 WHERE zoom_level = 9
|
|
UNION ALL
|
|
-- etldoc: waterway_z10 -> layer_waterway:z10
|
|
SELECT * FROM waterway_z10 WHERE zoom_level = 10
|
|
UNION ALL
|
|
-- etldoc: waterway_z11 -> layer_waterway:z11
|
|
SELECT * FROM waterway_z11 WHERE zoom_level = 11
|
|
UNION ALL
|
|
-- etldoc: waterway_z12 -> layer_waterway:z12
|
|
SELECT * FROM waterway_z12 WHERE zoom_level = 12
|
|
UNION ALL
|
|
-- etldoc: waterway_z13 -> layer_waterway:z13
|
|
SELECT * FROM waterway_z13 WHERE zoom_level = 13
|
|
UNION ALL
|
|
-- etldoc: waterway_z14 -> layer_waterway:z14
|
|
SELECT * FROM waterway_z14 WHERE zoom_level >= 14
|
|
) AS zoom_levels
|
|
WHERE geometry && bbox;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|