Skip to content

Commit 51b638a

Browse files
bchapuisAlexGacon
andauthored
Fix performance issue on PG Tile Store (#909, #912)
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 <alexandre.gacon@gmail.com>
1 parent 767b079 commit 51b638a

File tree

2 files changed

+23
-7
lines changed

2 files changed

+23
-7
lines changed

baremaps-core/src/main/java/org/apache/baremaps/tilestore/postgres/PostgresTileStore.java

Lines changed: 22 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -21,7 +21,7 @@
2121
import java.io.ByteArrayOutputStream;
2222
import java.io.OutputStream;
2323
import java.nio.ByteBuffer;
24-
import java.sql.*;
24+
import java.sql.ResultSet;
2525
import java.util.Map;
2626
import java.util.concurrent.ConcurrentHashMap;
2727
import java.util.zip.GZIPOutputStream;
@@ -64,7 +64,7 @@ public PostgresTileStore(DataSource datasource, Tileset tileset) {
6464

6565
/**
6666
* A record that holds the sql of a prepared statement and the number of parameters.
67-
*
67+
*
6868
* @param sql
6969
* @param parameters
7070
*/
@@ -163,10 +163,26 @@ protected static Query prepareQuery(Tileset tileset, int zoom) {
163163
.replace(";", "")
164164
.replace("?", "??")
165165
.replace("$zoom", String.valueOf(zoom));
166+
167+
// Append a new condition or a where clause
168+
if (querySql.toLowerCase().contains("where")) {
169+
querySql += " AND ";
170+
} else {
171+
querySql += " WHERE ";
172+
}
173+
174+
// Append the condition to the query sql
175+
querySql +=
176+
"geom IS NOT NULL AND geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))";
177+
166178
var querySqlWithParams = String.format(
167-
"SELECT ST_AsMVTGeom(t.geom, ST_TileEnvelope(?, ?, ?)) AS geom, t.tags - 'id' AS tags, t.id AS id "
168-
+ "FROM (%s) AS t WHERE t.geom IS NOT NULL "
169-
+ "AND t.geom && ST_TileEnvelope(?, ?, ?, margin => (64.0/4096))",
179+
"""
180+
SELECT
181+
tile.id AS id,
182+
tile.tags - 'id' AS tags,
183+
ST_AsMVTGeom(tile.geom, ST_TileEnvelope(?, ?, ?)) AS geom
184+
FROM (%s) as tile
185+
""",
170186
querySql);
171187
layerSql.append(querySqlWithParams);
172188

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

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

206222
return new Query(sql, paramCount);
207223
}

baremaps-core/src/test/java/org/apache/baremaps/tilestore/postgres/PostgresTileStoreTest.java

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -40,7 +40,7 @@ void prepareQuery() {
4040
List.of(new TilesetQuery(0, 20, "SELECT id, tags, geom FROM table")))));
4141
var query = PostgresTileStore.prepareQuery(tileset, 10);
4242
assertEquals(
43-
"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",
43+
"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",
4444
query.sql());
4545
}
4646
}

0 commit comments

Comments
 (0)