Jorge Sanz ace759590e
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-01-31 19:36:02 -05:00

58 lines
2.3 KiB
PL/PgSQL

-- etldoc: layer_city[shape=record fillcolor=lightpink, style="rounded,filled",
-- etldoc: label="layer_city | <z2_14> z2-z14+" ] ;
-- etldoc: osm_city_point -> layer_city:z2_14
CREATE OR REPLACE FUNCTION layer_city(bbox geometry, zoom_level int, pixel_width numeric)
RETURNS TABLE(osm_id bigint, geometry geometry, name text, name_en text, name_de text, tags hstore, place city_place, "rank" int, capital int) AS $$
SELECT * FROM (
SELECT osm_id, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
place, "rank", normalize_capital_level(capital) AS capital
FROM osm_city_point
WHERE geometry && bbox
AND ((zoom_level = 2 AND "rank" = 1)
OR (zoom_level BETWEEN 3 AND 7 AND "rank" <= zoom_level + 1)
)
UNION ALL
SELECT osm_id, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
place,
COALESCE("rank", gridrank + 10),
normalize_capital_level(capital) AS capital
FROM (
SELECT osm_id, geometry, name,
COALESCE(NULLIF(name_en, ''), name) AS name_en,
COALESCE(NULLIF(name_de, ''), name, name_en) AS name_de,
tags,
place, "rank", capital,
row_number() OVER (
PARTITION BY LabelGrid(geometry, 128 * pixel_width)
ORDER BY "rank" ASC NULLS LAST,
place ASC NULLS LAST,
population DESC NULLS LAST,
length(name) ASC
)::int AS gridrank
FROM osm_city_point
WHERE geometry && bbox
AND ((zoom_level = 7 AND place <= 'town'::city_place
OR (zoom_level BETWEEN 8 AND 10 AND place <= 'village'::city_place)
OR (zoom_level BETWEEN 11 AND 13 AND place <= 'suburb'::city_place)
OR (zoom_level >= 14)
))
) AS ranked_places
WHERE (zoom_level BETWEEN 7 AND 8 AND (gridrank <= 4 OR "rank" IS NOT NULL))
OR (zoom_level = 9 AND (gridrank <= 8 OR "rank" IS NOT NULL))
OR (zoom_level = 10 AND (gridrank <= 12 OR "rank" IS NOT NULL))
OR (zoom_level BETWEEN 11 AND 12 AND (gridrank <= 14 OR "rank" IS NOT NULL))
OR (zoom_level >= 13)
) as city_all;
$$
LANGUAGE SQL
IMMUTABLE PARALLEL SAFE;