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>
136 lines
5.4 KiB
PL/PgSQL
136 lines
5.4 KiB
PL/PgSQL
--TODO: Find a way to nicely generalize landcover
|
|
--CREATE TABLE IF NOT EXISTS landcover_grouped_gen2 AS (
|
|
-- SELECT osm_id, ST_Simplify((ST_Dump(geometry)).geom, 600) AS geometry, landuse, "natural", wetland
|
|
-- FROM (
|
|
-- SELECT max(osm_id) AS osm_id, ST_Union(ST_Buffer(geometry, 600)) AS geometry, landuse, "natural", wetland
|
|
-- FROM osm_landcover_polygon_gen1
|
|
-- GROUP BY LabelGrid(geometry, 15000000), landuse, "natural", wetland
|
|
-- ) AS grouped_measurements
|
|
--);
|
|
--CREATE INDEX IF NOT EXISTS landcover_grouped_gen2_geometry_idx ON landcover_grouped_gen2 USING gist(geometry);
|
|
|
|
CREATE OR REPLACE FUNCTION landcover_class(subclass VARCHAR) RETURNS TEXT AS $$
|
|
SELECT CASE
|
|
%%FIELD_MAPPING: class %%
|
|
END;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|
|
|
|
-- etldoc: ne_110m_glaciated_areas -> landcover_z0
|
|
CREATE OR REPLACE VIEW landcover_z0 AS (
|
|
SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass FROM ne_110m_glaciated_areas
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z2 AS (
|
|
-- etldoc: ne_50m_glaciated_areas -> landcover_z2
|
|
SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass FROM ne_50m_glaciated_areas
|
|
UNION ALL
|
|
-- etldoc: ne_50m_antarctic_ice_shelves_polys -> landcover_z2
|
|
SELECT NULL::bigint AS osm_id, geometry, 'ice_shelf'::text AS subclass FROM ne_50m_antarctic_ice_shelves_polys
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z5 AS (
|
|
-- etldoc: ne_10m_glaciated_areas -> landcover_z5
|
|
SELECT NULL::bigint AS osm_id, geometry, 'glacier'::text AS subclass FROM ne_10m_glaciated_areas
|
|
UNION ALL
|
|
-- etldoc: ne_10m_antarctic_ice_shelves_polys -> landcover_z5
|
|
SELECT NULL::bigint AS osm_id, geometry, 'ice_shelf'::text AS subclass FROM ne_10m_antarctic_ice_shelves_polys
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z7 AS (
|
|
-- etldoc: osm_landcover_polygon_gen7 -> landcover_z7
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen7
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z8 AS (
|
|
-- etldoc: osm_landcover_polygon_gen6 -> landcover_z8
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen6
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z9 AS (
|
|
-- etldoc: osm_landcover_polygon_gen5 -> landcover_z9
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen5
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z10 AS (
|
|
-- etldoc: osm_landcover_polygon_gen4 -> landcover_z10
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen4
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z11 AS (
|
|
-- etldoc: osm_landcover_polygon_gen3 -> landcover_z11
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen3
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z12 AS (
|
|
-- etldoc: osm_landcover_polygon_gen2 -> landcover_z12
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen2
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z13 AS (
|
|
-- etldoc: osm_landcover_polygon_gen1 -> landcover_z13
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon_gen1
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW landcover_z14 AS (
|
|
-- etldoc: osm_landcover_polygon -> landcover_z14
|
|
SELECT osm_id, geometry, subclass FROM osm_landcover_polygon
|
|
);
|
|
|
|
-- etldoc: layer_landcover[shape=record fillcolor=lightpink, style="rounded, filled", label="layer_landcover | <z0_1> z0-z1 | <z2_4> z2-z4 | <z5_6> z5-z6 |<z7> z7 |<z8> z8 |<z9> z9 |<z10> z10 |<z11> z11 |<z12> z12|<z13> z13|<z14_> z14+" ] ;
|
|
|
|
CREATE OR REPLACE FUNCTION layer_landcover(bbox geometry, zoom_level int)
|
|
RETURNS TABLE(osm_id bigint, geometry geometry, class text, subclass text) AS $$
|
|
SELECT osm_id, geometry,
|
|
landcover_class(subclass) AS class,
|
|
subclass
|
|
FROM (
|
|
-- etldoc: landcover_z0 -> layer_landcover:z0_1
|
|
SELECT * FROM landcover_z0
|
|
WHERE zoom_level BETWEEN 0 AND 1 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z2 -> layer_landcover:z2_4
|
|
SELECT * FROM landcover_z2
|
|
WHERE zoom_level BETWEEN 2 AND 4 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z5 -> layer_landcover:z5_6
|
|
SELECT * FROM landcover_z5
|
|
WHERE zoom_level BETWEEN 5 AND 6 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z7 -> layer_landcover:z7
|
|
SELECT *
|
|
FROM landcover_z7 WHERE zoom_level = 7 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z8 -> layer_landcover:z8
|
|
SELECT *
|
|
FROM landcover_z8 WHERE zoom_level = 8 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z9 -> layer_landcover:z9
|
|
SELECT *
|
|
FROM landcover_z9 WHERE zoom_level = 9 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z10 -> layer_landcover:z10
|
|
SELECT *
|
|
FROM landcover_z10 WHERE zoom_level = 10 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z11 -> layer_landcover:z11
|
|
SELECT *
|
|
FROM landcover_z11 WHERE zoom_level = 11 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z12 -> layer_landcover:z12
|
|
SELECT *
|
|
FROM landcover_z12 WHERE zoom_level = 12 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z13 -> layer_landcover:z13
|
|
SELECT *
|
|
FROM landcover_z13 WHERE zoom_level = 13 AND geometry && bbox
|
|
UNION ALL
|
|
-- etldoc: landcover_z14 -> layer_landcover:z14_
|
|
SELECT *
|
|
FROM landcover_z14 WHERE zoom_level >= 14 AND geometry && bbox
|
|
) AS zoom_levels;
|
|
$$
|
|
LANGUAGE SQL
|
|
IMMUTABLE PARALLEL SAFE;
|