Skip to content

Commit

Permalink
Fix performance issue on PG Tile Store (#909, #912)
Browse files Browse the repository at this point in the history
The query optimizer of Postgres 15 is not able to push conditions down when using sub-queries. Therefore, we now append the spatial conditions to the sub-query. The unit tests have been adapted accordingly. A more robust solution involving a query parser will be devised (#913) in the future to account for more complex queries (GROUP BY, HAVING, etc.).

---------

Co-authored-by: AlexGacon <[email protected]>
  • Loading branch information
bchapuis and AlexGacon authored Jan 9, 2025
1 parent 767b079 commit 51b638a
Show file tree
Hide file tree
Showing 2 changed files with 23 additions and 7 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@
import java.io.ByteArrayOutputStream;
import java.io.OutputStream;
import java.nio.ByteBuffer;
import java.sql.*;
import java.sql.ResultSet;
import java.util.Map;
import java.util.concurrent.ConcurrentHashMap;
import java.util.zip.GZIPOutputStream;
Expand Down Expand Up @@ -64,7 +64,7 @@ public PostgresTileStore(DataSource datasource, Tileset tileset) {

/**
* A record that holds the sql of a prepared statement and the number of parameters.
*
*
* @param sql
* @param parameters
*/
Expand Down Expand Up @@ -163,10 +163,26 @@ protected static Query prepareQuery(Tileset tileset, int zoom) {
.replace(";", "")
.replace("?", "??")
.replace("$zoom", String.valueOf(zoom));

// Append a new condition or a where clause
if (querySql.toLowerCase().contains("where")) {
querySql += " AND ";
} else {
querySql += " WHERE ";
}

// Append the condition to the query sql
querySql +=
"geom IS NOT NULL AND geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))";

var querySqlWithParams = String.format(
"SELECT ST_AsMVTGeom(t.geom, ST_TileEnvelope(?, ?, ?)) AS geom, t.tags - 'id' AS tags, t.id AS id "
+ "FROM (%s) AS t WHERE t.geom IS NOT NULL "
+ "AND t.geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))",
"""
SELECT
tile.id AS id,
tile.tags - 'id' AS tags,
ST_AsMVTGeom(tile.geom, ST_TileEnvelope(?, ?, ?)) AS geom
FROM (%s) as tile
""",
querySql);
layerSql.append(querySqlWithParams);

Expand Down Expand Up @@ -201,7 +217,7 @@ protected static Query prepareQuery(Tileset tileset, int zoom) {
tileSql.append(tileQueryTail);

// Format the sql query
var sql = tileSql.toString().replace("\n", " ");
var sql = tileSql.toString().replaceAll("\\s+", " ");

return new Query(sql, paramCount);
}
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -40,7 +40,7 @@ void prepareQuery() {
List.of(new TilesetQuery(0, 20, "SELECT id, tags, geom FROM table")))));
var query = PostgresTileStore.prepareQuery(tileset, 10);
assertEquals(
"SELECT (SELECT ST_AsMVT(mvtGeom.*, 'a') FROM (SELECT ST_AsMVTGeom(t.geom, ST_TileEnvelope(?, ?, ?)) AS geom, t.tags - 'id' AS tags, t.id AS id FROM (SELECT id, tags, geom FROM table) AS t WHERE t.geom IS NOT NULL AND t.geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))) AS mvtGeom) || (SELECT ST_AsMVT(mvtGeom.*, 'b') FROM (SELECT ST_AsMVTGeom(t.geom, ST_TileEnvelope(?, ?, ?)) AS geom, t.tags - 'id' AS tags, t.id AS id FROM (SELECT id, tags, geom FROM table) AS t WHERE t.geom IS NOT NULL AND t.geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))) AS mvtGeom) AS mvtTile",
"SELECT (SELECT ST_AsMVT(mvtGeom.*, 'a') FROM (SELECT tile.id AS id, tile.tags - 'id' AS tags, ST_AsMVTGeom(tile.geom, ST_TileEnvelope(?, ?, ?)) AS geom FROM (SELECT id, tags, geom FROM table WHERE geom IS NOT NULL AND geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))) as tile ) AS mvtGeom) || (SELECT ST_AsMVT(mvtGeom.*, 'b') FROM (SELECT tile.id AS id, tile.tags - 'id' AS tags, ST_AsMVTGeom(tile.geom, ST_TileEnvelope(?, ?, ?)) AS geom FROM (SELECT id, tags, geom FROM table WHERE geom IS NOT NULL AND geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))) as tile ) AS mvtGeom) AS mvtTile",
query.sql());
}
}

0 comments on commit 51b638a

Please sign in to comment.