Many hyperlinks are disabled.
Use anonymous login
to enable hyperlinks.
Overview
Artifact ID: | a027126d7e8b7b78fa1b0d9dd1e7071278910314 |
---|---|
Page Name: | About ST_Subdivide() |
Date: | 2019-02-24 17:26:15 |
Original User: | sandro |
Parent: | 22f4f550841c61347fc9eddb86d9cdbc1fe4201c (diff) |
Next | 6735e789ed2462fdfd19ea2528369887772c793f |
Content
About ST_Subdivide()Starting with version 5.0.0 SpatiaLite supports ST_Subdivide(), an advanced SQL function already available on PostGIS.The implementation is very similar in both Spatial DBMSes because in PostGIS the function is created with the internal lwgeom library, and in SpatiaLite with librttopo, which is a universal porting of lwgeom without PostGIS. A short rationale: processing huge geometries having an impressive number of Vertices (many thousands or even more) is an extremely slow process. Subdividing them into many smaller parts (while preserving full topological consistency) usually results in a satisfying processing speed. This is exactly the intended scope of ST_Subdivide():
Basic SamplesThe following sampless are based on the, freely available, am_reg_multipart Shapefile and can be download from here here (search for Ambiti Amministrativi - Administrative Boundaries).This Shapefile supports a very accurate and precise map representation, and the main exterior ring has more than 100,000+ Vertices. It's a very good example of a Geometry, that is so huge and will cause any Spatial operator, such as ST_Intersects, ST_Touches, ST_Covers etc., to become extremely slow.
However, a big disadvantage should be always be considered when using the multi-part collections returned by ST_Subdivide(). At least in the case of MultiPolygons, any collection returned by ST_Subdivide() is inherently invalid, as the following SQL query demonstrates: SELECT ST_IsValid(ST_Subdivide(geometry)) FROM tuscany; --------- 0It's not at all difficult to understand why this is so. Accordingly to standard OGC/SFS rules: two single-part Polygons, belonging to the same MultiPolygon, are always forbidden to share a common border. More precisely: they can only touch on specific point(s), but they can never share a common boundary.
Advanced SamplesNow we'll go on to explore the real effectiveness of ST_Subdivide() for one of the most common Spatial Problems: identifying all intersections between a dataset of the POINT type and a huge Polygon/MultiPolygon.During this second test we'll use the following datasets:
A first simple attemptSELECT Count(*) FROM civici AS c LEFT JOIN tuscany AS t ON (ST_Intersects(c.geometry, t.geometry) = 1); SELECT Count(*) FROM civici AS c LEFT JOIN tuscany AS t ON (ST_Intersects(c.geometry, t.geometry) = 1 AND c.rowid IN ( SELECT rowid FROM SpatialIndex WHERE f_table_name = 'civici' AND search_frame = t.geometry));The only difference between the two SQL queries is in that the second one explicitly calls the Spatial Index. Actual findings:
A second attempt based on ST_Subdivide() and VirtualElementaryCREATE TABLE xx (id INTEGER PRIMARY KEY); SELECT AddGeometryColumn('xx', 'geom', 3003, 'MULTIPOLYGON', 'XY'); INSERT INTO xx VALUES (1, NULL);We'll start first by creating a convenience Table, which will store the result of ST_Subdivide(). This is a very simple Table:
UPDATE xx SET geom = (SELECT ST_Subdivide(geometry, 2048) FROM tuscany) WHERE id = 1; SELECT Count(*) FROM ElementaryGeometries AS t JOIN civici AS c ON (ST_Intersects(c.geometry, t.geometry) = 1 AND c.rowid IN ( SELECT rowid FROM SpatialIndex WHERE f_table_name = 'civici' AND search_frame = t.geometry)) WHERE f_table_name = 'xx' AND origin_rowid = 1; ---------------- 1480991 (in 38.094 seconds) UPDATE xx SET geom = (SELECT ST_Subdivide(geometry, 512) FROM tuscany) WHERE id = 1; SELECT Count(*) FROM ElementaryGeometries AS t JOIN civici AS c ON (ST_Intersects(c.geometry, t.geometry) = 1 AND c.rowid IN ( SELECT rowid FROM SpatialIndex WHERE f_table_name = 'civici' AND search_frame = t.geometry)) WHERE f_table_name = 'xx' AND origin_rowid = 1; ---------------- 1480991 (in 12.617 seconds) UPDATE xx SET geom = (SELECT ST_Subdivide(geometry) FROM tuscany) WHERE id = 1; SELECT Count(*) FROM ElementaryGeometries AS t JOIN civici AS c ON (ST_Intersects(c.geometry, t.geometry) = 1 AND c.rowid IN ( SELECT rowid FROM SpatialIndex WHERE f_table_name = 'civici' AND search_frame = t.geometry)) WHERE f_table_name = 'xx' AND origin_rowid = 1; ---------------- 1480991 (in 9.534 seconds)Quick evaluation:
A final experimental attempt based on a pure SQL approachAnother alternative mechanism, based on pure SQL and not requiring the use of ElementaryGeometries or of a convenience Table is:WITH RECURSIVE magic(n, geom) AS ( VALUES(1, (SELECT ST_Subdivide(geometry, 2048) FROM tuscany)) UNION ALL SELECT n + 1, geom FROM geom_ind WHERE ST_GeometryN(geom, n) IS NOT NULL ) SELECT n, ST_GeometryN(geom, n) FROM magic;
|