├── package.json ├── .travis.yml ├── Makefile ├── src ├── CleanInt.sql ├── CleanNumeric.sql ├── MercLength.sql ├── MercBuffer.sql ├── Z.sql ├── MercDWithin.sql ├── Bounds.sql ├── ZRes.sql ├── LineLabel.sql ├── TileBBox.sql ├── MakeArc.sql ├── OrientedEnvelope.sql ├── SmartShrink.sql ├── ToPoint.sql ├── LabelGrid.sql ├── Sieve.sql └── LargestPart.sql ├── CONTRIBUTING.md ├── LICENSE.md ├── CHANGELOG.md ├── test └── sql-test.sh ├── README.md └── postgis-vt-util.sql /package.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "@mapbox/postgis-vt-util", 3 | "version": "1.2.1", 4 | "description": "PostGIS helper functions for making vector tiles", 5 | "main": "./package.json", 6 | "scripts": { 7 | "test": "test/sql-test.sh" 8 | } 9 | } 10 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: node_js 2 | node_js: 3 | - "0.10" 4 | sudo: false 5 | addons: 6 | postgresql: 9.3 7 | before_install: 8 | - psql -U postgres -c "create database testing_postgis_vt_util" 9 | - psql -U postgres -d testing_postgis_vt_util -c "create extension postgis" 10 | script: 11 | - npm test 12 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | README.md: postgis-vt-util.sql 2 | sed -n -i'' -e '1,/ 27 | 28 | 29 | ### Bounds ### 30 | 31 | Returns an array of the bounding coordinates of the input geometry - 32 | `{xmin, ymin, xmax, ymax}`. Useful for interfacing with software outside of 33 | PostGIS, among other things. 34 | 35 | If an SRID is specified the output will be the bounds of the reprojected 36 | geometry, not a reprojected bounding box. 37 | 38 | __Parameters:__ 39 | 40 | - `geometry` g - Any geometry 41 | - `integer` srid (optional) - The desired output SRID of the bounds, if 42 | different from the input. 43 | 44 | __Returns:__ `float[]` - an array of 4 floats, `{xmin, ymin, xmax, ymax}` 45 | 46 | 47 | ### CleanInt ### 48 | 49 | Returns the input text as an integer if possible, otherwise null. 50 | 51 | __Parameters:__ 52 | 53 | - `text` i - Text that you would like as an integer. 54 | 55 | __Returns:__ `integer` 56 | 57 | 58 | ### CleanNumeric ### 59 | 60 | Returns the input text as an numeric if possible, otherwise null. 61 | 62 | __Parameters:__ 63 | 64 | - `text` i - Text that you would like as an numeric. 65 | 66 | __Returns:__ `numeric` 67 | 68 | 69 | ### LabelGrid ### 70 | 71 | Returns a "hash" of a geometry's position on a specified grid to use in a GROUP 72 | BY clause. Useful for limiting the density of points or calculating a localized 73 | importance ranking. 74 | 75 | This function is most useful on point geometries intended for label placement 76 | (eg points of interest) but will accept any geometry type. It is usually used 77 | as part of either a `DISTINCT ON` expression or a `rank()` window function. 78 | 79 | __Parameters:__ 80 | 81 | - `geometry` g - A geometry. 82 | - `numeric` grid_size - The cell size of the desired grouping grid. 83 | 84 | __Returns:__ `text` - A text representation of the labelgrid cell 85 | 86 | __Example Mapbox Studio query:__ 87 | 88 | ```sql 89 | ( SELECT * FROM ( 90 | SELECT DISTINCT ON (LabelGrid(geom, 64*!pixel_width!)) * FROM ( 91 | SELECT id, name, class, population, geom FROM city_points 92 | WHERE geom && !bbox! 93 | ) AS raw 94 | ORDER BY LabelGrid(geom, 64*!pixel_width!), population DESC, id 95 | ) AS filtered 96 | ORDER BY population DESC, id 97 | ) AS final 98 | ``` 99 | 100 | 101 | ### LargestPart ### 102 | 103 | Returns the largest single part of a multigeometry. 104 | 105 | - Given a multipolygon or a geometrycollection containing at least one polygon, 106 | this function will return the single polygon with the largest area. 107 | - Given a multilinestring or a geometrycollection containing at least one 108 | linestring and no polygons, this function will return the single linestring 109 | with the longest length. 110 | - Given a single point, line, or polygon, the original geometry will be 111 | returned. 112 | - Given any other geometry type the result of `ST_GeometryN(, 1)` will be 113 | returned. (See the documentation for that function.) 114 | 115 | __Parameters:__ 116 | 117 | - `geometry` g - A geometry. 118 | 119 | __Returns:__ `geometry` - The largest single part of the input geometry. 120 | 121 | 122 | ### LineLabel ### 123 | 124 | This function tries to estimate whether a line geometry would be long enough to 125 | have the given text placed along it at the specified scale. 126 | 127 | It is useful in vector tile queries to filter short lines from zoom levels 128 | where they would be unlikely to have text places on them anyway. 129 | 130 | __Parameters:__ 131 | 132 | - `numeric` zoom - The Web Mercator zoom level you are considering. 133 | - `text` label - The label text that you will be placing along the line. 134 | - `geometry(linestring)` g - A line geometry. 135 | 136 | __Returns:__ `boolean` 137 | 138 | 139 | ### MakeArc ### 140 | 141 | Creates a CircularString arc based on 3 input points. 142 | 143 | __Parameters:__ 144 | 145 | - `geometry(point)` p0 - The starting point of the arc. 146 | - `geometry(point)` p1 - A point along the path of the arc. 147 | - `geometry(point)` p2 - The end point of the arc. 148 | - `integer` srid (optional) - Sets the SRID of the output geometry. Useful 149 | when input points have no SRID. If not specified the SRID of the first 150 | input geometry will be assigned to the output. 151 | 152 | __Returns:__ `geometry(linestring)` 153 | 154 | __Examples:__ 155 | 156 | 157 | ```sql 158 | SELECT MakeArc( 159 | ST_MakePoint(-100, 0), 160 | ST_MakePoint(0, 100), 161 | ST_MakePoint(100, 0), 162 | 3857 163 | ); 164 | ``` 165 | 166 | 167 | ### MercBuffer ### 168 | 169 | Wraps ST_Buffer to adjust the buffer distance by latitude in order to 170 | approximate real-world measurements. Assumes input geometries are Web Mercator 171 | and input distances are real-world meters. Accuracy decreases for larger buffer 172 | distances and at extreme latitudes. 173 | 174 | __Parameters:__ 175 | 176 | - `geometry` g - A geometry to buffer. 177 | - `numeric` distance - The distance you would like to buffer, in real-world 178 | meters. 179 | 180 | __Returns:__ `geometry` 181 | 182 | 183 | ### MercDWithin ### 184 | 185 | Wrapper for ST_DWithin that adjusts distance by latitude to approximate real- 186 | world measurements. Assumes input geometries are Web Mercator and input 187 | distances are real-world meters. Accuracy decreases for larger distances and at 188 | extreme latitudes. 189 | 190 | __Parameters:__ 191 | 192 | - `geometry` g1 - The first geometry. 193 | - `geometry` g2 - The second geometry. 194 | - `numeric` distance - The maximum distance to check against 195 | 196 | __Returns:__ `boolean` 197 | 198 | 199 | ### MercLength ### 200 | 201 | Wrapper for ST_Length that adjusts distance by latitude to approximate real- 202 | world measurements. Assumes input geometries are Web Mercator. Accuracy 203 | decreases for larger y-axis ranges of the input. 204 | 205 | __Parameters:__ 206 | 207 | - `geometry` g - A (multi)linestring geometry. 208 | 209 | __Returns:__ `numeric` 210 | 211 | 212 | ### OrientedEnvelope ### 213 | 214 | Returns an oriented minimum-bounding rectangle for a geometry. 215 | 216 | __Parameters:__ 217 | 218 | - `geometry` g - A geometry. 219 | 220 | __Returns:__ `geometry(polygon)` 221 | 222 | 223 | ### Sieve ### 224 | 225 | Filters small rings (both inner and outer) from a multipolygon based on area. 226 | 227 | __Parameters:__ 228 | 229 | - `geometry` g - A multipolygon 230 | - `float` area_threshold - the minimum ring area to keep. 231 | 232 | __Returns:__ `geometry` - a polygon or multipolygon 233 | 234 | 235 | ### SmartShrink ### 236 | 237 | Buffers a polygon progressively (on an exponential scale) until the 238 | area of the result hits a certain threshold ratio to the original area. 239 | The result is also simplified with a tolerance matching the inset 240 | distance. 241 | 242 | __Parameters:__ 243 | 244 | - `geometry` g - A (multi)polygon. 245 | - `float` ratio - The threshold for how much smaller (by area) you want 246 | the shrunk polygon to be compared to the original. Eg a value of 0.6 247 | would result in a polygon that is at least 60% as large as the input. 248 | - `boolean` simplify - Defaults to false. Whether or not you would 249 | like the shrunk geometry simplified. 250 | 251 | __Returns:__ `geometry` 252 | 253 | 254 | ### TileBBox ### 255 | 256 | Given a Web Mercator tile ID as (z, x, y), returns a bounding-box 257 | geometry of the area covered by that tile. 258 | 259 | __Parameters:__ 260 | 261 | - `integer` z - A tile zoom level. 262 | - `integer` x - A tile x-position. 263 | - `integer` y - A tile y-position. 264 | - `integer` srid - SRID of the desired target projection of the bounding 265 | box. Defaults to 3857 (Web Mercator). 266 | 267 | __Returns:__ `geometry(polygon)` 268 | 269 | 270 | ### ToPoint ### 271 | 272 | Helper to wrap ST_PointOnSurface, ST_MakeValid. This is needed because 273 | of a ST_PointOnSurface bug in geos < 3.3.8 where POLYGON EMPTY can pass 274 | through as a polygon geometry. 275 | If the input geometry is a polygon with less than 5 points the ST_Centroid 276 | of the polygon will be used instead of ST_PointOnSurface to speed up calculation. 277 | 278 | __Parameters:__ 279 | 280 | - `geometry` g - A geometry. 281 | 282 | __Returns:__ `geometry(point)` 283 | 284 | __Example:__ 285 | 286 | ```sql 287 | -- Create an additional point geometry colums for labeling 288 | ALTER TABLE city_park ADD COLUMN geom_label geometry(point); 289 | UPDATE city_park SET geom_label = ToPoint(geom); 290 | ``` 291 | 292 | 293 | ### ZRES ### 294 | 295 | Takes a web mercator zoom level and returns the pixel resolution for that 296 | scale, assuming 256x256 pixel tiles. Non-integer zoom levels are accepted. 297 | 298 | __Parameters:__ 299 | 300 | - `integer` or `float` z - A Web Mercator zoom level. 301 | 302 | __Returns:__ `float` 303 | 304 | __Examples:__ 305 | 306 | ```sql 307 | -- Delete all polygons smaller than 1px square at zoom level 10 308 | DELETE FROM water_polygons WHERE sqrt(ST_Area(geom)) < ZRes(10); 309 | 310 | -- Simplify geometries to a resolution appropriate for zoom level 10 311 | UPDATE water_polygons SET geom = ST_Simplify(geom, ZRes(10)); 312 | ``` 313 | 314 | 315 | ### Z ### 316 | 317 | Returns a Web Mercator integer zoom level given a scale denominator. 318 | 319 | Useful with Mapnik's !scale_denominator! token in vector tile source 320 | queries. 321 | 322 | __Parameters:__ 323 | 324 | - `numeric` scale_denominator - The denominator of the scale, eg `250000` 325 | for a 1:250,000 scale. 326 | 327 | __Returns:__ `integer` 328 | 329 | __Example Mapbox Studio query:__ 330 | 331 | ```sql 332 | ( SELECT * FROM roads 333 | WHERE Z(!scale_denominator!) >= 12 334 | ) AS data 335 | ``` 336 | 337 | -------------------------------------------------------------------------------- /postgis-vt-util.sql: -------------------------------------------------------------------------------- 1 | /****************************************************************************** 2 | ### Bounds ### 3 | 4 | Returns an array of the bounding coordinates of the input geometry - 5 | `{xmin, ymin, xmax, ymax}`. Useful for interfacing with software outside of 6 | PostGIS, among other things. 7 | 8 | If an SRID is specified the output will be the bounds of the reprojected 9 | geometry, not a reprojected bounding box. 10 | 11 | __Parameters:__ 12 | 13 | - `geometry` g - Any geometry 14 | - `integer` srid (optional) - The desired output SRID of the bounds, if 15 | different from the input. 16 | 17 | __Returns:__ `float[]` - an array of 4 floats, `{xmin, ymin, xmax, ymax}` 18 | ******************************************************************************/ 19 | create or replace function Bounds (g geometry, srid integer = null) 20 | returns float[] 21 | language plpgsql immutable as 22 | $func$ 23 | begin 24 | if srid is not null then 25 | g := ST_Transform(g, srid); 26 | end if; 27 | 28 | return array[ 29 | ST_XMin(g), 30 | ST_YMin(g), 31 | ST_XMax(g), 32 | ST_YMax(g) 33 | ]; 34 | end; 35 | $func$; 36 | 37 | 38 | /****************************************************************************** 39 | ### CleanInt ### 40 | 41 | Returns the input text as an integer if possible, otherwise null. 42 | 43 | __Parameters:__ 44 | 45 | - `text` i - Text that you would like as an integer. 46 | 47 | __Returns:__ `integer` 48 | ******************************************************************************/ 49 | create or replace function CleanInt (i text) 50 | returns integer 51 | language plpgsql immutable as 52 | $func$ 53 | begin 54 | return cast(cast(i as float) as integer); 55 | exception 56 | when invalid_text_representation then 57 | return null; 58 | when numeric_value_out_of_range then 59 | return null; 60 | end; 61 | $func$; 62 | 63 | 64 | /****************************************************************************** 65 | ### CleanNumeric ### 66 | 67 | Returns the input text as an numeric if possible, otherwise null. 68 | 69 | __Parameters:__ 70 | 71 | - `text` i - Text that you would like as an numeric. 72 | 73 | __Returns:__ `numeric` 74 | ******************************************************************************/ 75 | create or replace function CleanNumeric (i text) 76 | returns numeric 77 | language plpgsql immutable as 78 | $$ 79 | begin 80 | return cast(cast(i as float) as numeric); 81 | exception 82 | when invalid_text_representation then 83 | return null; 84 | when numeric_value_out_of_range then 85 | return null; 86 | end; 87 | $$; 88 | 89 | 90 | /****************************************************************************** 91 | ### LabelGrid ### 92 | 93 | Returns a "hash" of a geometry's position on a specified grid to use in a GROUP 94 | BY clause. Useful for limiting the density of points or calculating a localized 95 | importance ranking. 96 | 97 | This function is most useful on point geometries intended for label placement 98 | (eg points of interest) but will accept any geometry type. It is usually used 99 | as part of either a `DISTINCT ON` expression or a `rank()` window function. 100 | 101 | __Parameters:__ 102 | 103 | - `geometry` g - A geometry. 104 | - `numeric` grid_size - The cell size of the desired grouping grid. 105 | 106 | __Returns:__ `text` - A text representation of the labelgrid cell 107 | 108 | __Example Mapbox Studio query:__ 109 | 110 | ```sql 111 | ( SELECT * FROM ( 112 | SELECT DISTINCT ON (LabelGrid(geom, 64*!pixel_width!)) * FROM ( 113 | SELECT id, name, class, population, geom FROM city_points 114 | WHERE geom && !bbox! 115 | ) AS raw 116 | ORDER BY LabelGrid(geom, 64*!pixel_width!), population DESC, id 117 | ) AS filtered 118 | ORDER BY population DESC, id 119 | ) AS final 120 | ``` 121 | ******************************************************************************/ 122 | create or replace function LabelGrid ( 123 | g geometry, 124 | grid_size numeric 125 | ) 126 | returns text 127 | language plpgsql immutable as 128 | $func$ 129 | begin 130 | if grid_size <= 0 then 131 | return 'null'; 132 | end if; 133 | if GeometryType(g) <> 'POINT' then 134 | g := (select (ST_DumpPoints(g)).geom limit 1); 135 | end if; 136 | return ST_AsText(ST_SnapToGrid( 137 | g, 138 | grid_size/2, -- x origin 139 | grid_size/2, -- y origin 140 | grid_size, -- x size 141 | grid_size -- y size 142 | )); 143 | end; 144 | $func$; 145 | 146 | 147 | /****************************************************************************** 148 | ### LargestPart ### 149 | 150 | Returns the largest single part of a multigeometry. 151 | 152 | - Given a multipolygon or a geometrycollection containing at least one polygon, 153 | this function will return the single polygon with the largest area. 154 | - Given a multilinestring or a geometrycollection containing at least one 155 | linestring and no polygons, this function will return the single linestring 156 | with the longest length. 157 | - Given a single point, line, or polygon, the original geometry will be 158 | returned. 159 | - Given any other geometry type the result of `ST_GeometryN(, 1)` will be 160 | returned. (See the documentation for that function.) 161 | 162 | __Parameters:__ 163 | 164 | - `geometry` g - A geometry. 165 | 166 | __Returns:__ `geometry` - The largest single part of the input geometry. 167 | ******************************************************************************/ 168 | create or replace function LargestPart (g geometry) 169 | returns geometry 170 | language plpgsql immutable as 171 | $func$ 172 | begin 173 | -- Non-multi geometries can just pass through 174 | if GeometryType(g) in ('POINT', 'LINESTRING', 'POLYGON') then 175 | return g; 176 | -- MultiPolygons and GeometryCollections that contain Polygons 177 | elsif not ST_IsEmpty(ST_CollectionExtract(g, 3)) then 178 | return ( 179 | select geom 180 | from ( 181 | select (ST_Dump(ST_CollectionExtract(g,3))).geom 182 | ) as dump 183 | order by ST_Area(geom) desc 184 | limit 1 185 | ); 186 | -- MultiLinestrings and GeometryCollections that contain Linestrings 187 | elsif not ST_IsEmpty(ST_CollectionExtract(g, 2)) then 188 | return ( 189 | select geom 190 | from ( 191 | select (ST_Dump(ST_CollectionExtract(g,2))).geom 192 | ) as dump 193 | order by ST_Length(geom) desc 194 | limit 1 195 | ); 196 | -- Other geometry types are not really handled but we at least try to 197 | -- not return a MultiGeometry. 198 | else 199 | return ST_GeometryN(g, 1); 200 | end if; 201 | end; 202 | $func$; 203 | 204 | 205 | /****************************************************************************** 206 | ### LineLabel ### 207 | 208 | This function tries to estimate whether a line geometry would be long enough to 209 | have the given text placed along it at the specified scale. 210 | 211 | It is useful in vector tile queries to filter short lines from zoom levels 212 | where they would be unlikely to have text places on them anyway. 213 | 214 | __Parameters:__ 215 | 216 | - `numeric` zoom - The Web Mercator zoom level you are considering. 217 | - `text` label - The label text that you will be placing along the line. 218 | - `geometry(linestring)` g - A line geometry. 219 | 220 | __Returns:__ `boolean` 221 | ******************************************************************************/ 222 | create or replace function LineLabel ( 223 | zoom numeric, 224 | label text, 225 | g geometry 226 | ) 227 | returns boolean 228 | language plpgsql immutable as 229 | $func$ 230 | begin 231 | if zoom > 20 or ST_Length(g) = 0 then 232 | -- if length is 0 geom is (probably) a point; keep it 233 | return true; 234 | else 235 | return length(label) between 1 and ST_Length(g)/(2^(20-zoom)); 236 | end if; 237 | end; 238 | $func$; 239 | 240 | 241 | /****************************************************************************** 242 | ### MakeArc ### 243 | 244 | Creates a CircularString arc based on 3 input points. 245 | 246 | __Parameters:__ 247 | 248 | - `geometry(point)` p0 - The starting point of the arc. 249 | - `geometry(point)` p1 - A point along the path of the arc. 250 | - `geometry(point)` p2 - The end point of the arc. 251 | - `integer` srid (optional) - Sets the SRID of the output geometry. Useful 252 | when input points have no SRID. If not specified the SRID of the first 253 | input geometry will be assigned to the output. 254 | 255 | __Returns:__ `geometry(linestring)` 256 | 257 | __Examples:__ 258 | 259 | 260 | ```sql 261 | SELECT MakeArc( 262 | ST_MakePoint(-100, 0), 263 | ST_MakePoint(0, 100), 264 | ST_MakePoint(100, 0), 265 | 3857 266 | ); 267 | ``` 268 | ******************************************************************************/ 269 | create or replace function MakeArc ( 270 | p0 geometry(point), 271 | p1 geometry(point), 272 | p2 geometry(point), 273 | srid integer default null 274 | ) 275 | returns geometry 276 | language plpgsql immutable as 277 | $func$ 278 | begin 279 | return ST_CurveToLine(ST_GeomFromText( 280 | 'CIRCULARSTRING(' 281 | || ST_X(p0) || ' ' || ST_Y(p0) || ', ' 282 | || ST_X(p1) || ' ' || ST_Y(p1) || ', ' 283 | || ST_X(p2) || ' ' || ST_Y(p2) || ')', 284 | coalesce(srid, ST_SRID(p0)) 285 | )); 286 | end; 287 | $func$; 288 | 289 | 290 | /****************************************************************************** 291 | ### MercBuffer ### 292 | 293 | Wraps ST_Buffer to adjust the buffer distance by latitude in order to 294 | approximate real-world measurements. Assumes input geometries are Web Mercator 295 | and input distances are real-world meters. Accuracy decreases for larger buffer 296 | distances and at extreme latitudes. 297 | 298 | __Parameters:__ 299 | 300 | - `geometry` g - A geometry to buffer. 301 | - `numeric` distance - The distance you would like to buffer, in real-world 302 | meters. 303 | 304 | __Returns:__ `geometry` 305 | ******************************************************************************/ 306 | create or replace function MercBuffer (g geometry, distance numeric) 307 | returns geometry 308 | language plpgsql immutable as 309 | $func$ 310 | begin 311 | return ST_Buffer( 312 | g, 313 | distance / cos(radians(ST_Y(ST_Transform(ST_Centroid(g),4326)))) 314 | ); 315 | end; 316 | $func$; 317 | 318 | 319 | /****************************************************************************** 320 | ### MercDWithin ### 321 | 322 | Wrapper for ST_DWithin that adjusts distance by latitude to approximate real- 323 | world measurements. Assumes input geometries are Web Mercator and input 324 | distances are real-world meters. Accuracy decreases for larger distances and at 325 | extreme latitudes. 326 | 327 | __Parameters:__ 328 | 329 | - `geometry` g1 - The first geometry. 330 | - `geometry` g2 - The second geometry. 331 | - `numeric` distance - The maximum distance to check against 332 | 333 | __Returns:__ `boolean` 334 | ******************************************************************************/ 335 | create or replace function MercDWithin ( 336 | g1 geometry, 337 | g2 geometry, 338 | distance numeric 339 | ) 340 | returns boolean 341 | language plpgsql immutable as 342 | $func$ 343 | begin 344 | return ST_Dwithin( 345 | g1, 346 | g2, 347 | distance / cos(radians(ST_Y(ST_Transform(ST_Centroid(g1),4326)))) 348 | ); 349 | end; 350 | $func$; 351 | 352 | 353 | /****************************************************************************** 354 | ### MercLength ### 355 | 356 | Wrapper for ST_Length that adjusts distance by latitude to approximate real- 357 | world measurements. Assumes input geometries are Web Mercator. Accuracy 358 | decreases for larger y-axis ranges of the input. 359 | 360 | __Parameters:__ 361 | 362 | - `geometry` g - A (multi)linestring geometry. 363 | 364 | __Returns:__ `numeric` 365 | ******************************************************************************/ 366 | create or replace function MercLength (g geometry) 367 | returns numeric 368 | language plpgsql immutable as 369 | $func$ 370 | begin 371 | return ST_Length(g) * cos(radians(ST_Y(ST_Transform(ST_Centroid(g),4326)))); 372 | end; 373 | $func$; 374 | 375 | 376 | /****************************************************************************** 377 | ### OrientedEnvelope ### 378 | 379 | Returns an oriented minimum-bounding rectangle for a geometry. 380 | 381 | __Parameters:__ 382 | 383 | - `geometry` g - A geometry. 384 | 385 | __Returns:__ `geometry(polygon)` 386 | ******************************************************************************/ 387 | create or replace function OrientedEnvelope (g geometry) 388 | returns geometry(polygon) 389 | language plpgsql immutable as 390 | $func$ 391 | declare 392 | p record; 393 | p0 geometry(point); 394 | p1 geometry(point); 395 | ctr geometry(point); 396 | angle_min float; 397 | angle_cur float; 398 | area_min float; 399 | area_cur float; 400 | begin 401 | -- Approach is based on the rotating calipers method: 402 | -- 403 | g := ST_ConvexHull(g); 404 | ctr := ST_Centroid(g); 405 | for p in (select (ST_DumpPoints(g)).geom) loop 406 | p0 := p1; 407 | p1 := p.geom; 408 | if p0 is null then 409 | continue; 410 | end if; 411 | angle_cur := ST_Azimuth(p0, p1) - pi()/2; 412 | area_cur := ST_Area(ST_Envelope(ST_Rotate(g, angle_cur, ctr))); 413 | if area_cur < area_min or area_min is null then 414 | area_min := area_cur; 415 | angle_min := angle_cur; 416 | end if; 417 | end loop; 418 | return ST_Rotate(ST_Envelope(ST_Rotate(g, angle_min, ctr)), -angle_min, ctr); 419 | end; 420 | $func$; 421 | 422 | 423 | /****************************************************************************** 424 | ### Sieve ### 425 | 426 | Filters small rings (both inner and outer) from a multipolygon based on area. 427 | 428 | __Parameters:__ 429 | 430 | - `geometry` g - A multipolygon 431 | - `float` area_threshold - the minimum ring area to keep. 432 | 433 | __Returns:__ `geometry` - a polygon or multipolygon 434 | ******************************************************************************/ 435 | create or replace function Sieve (g geometry, area_threshold float) 436 | returns geometry 437 | language sql immutable as 438 | $func$ 439 | with exploded as ( 440 | -- First use ST_Dump to explode the input multipolygon 441 | -- to individual polygons. 442 | select (ST_Dump(g)).geom 443 | ), rings as ( 444 | -- Next use ST_DumpRings to turn all of the inner and outer rings 445 | -- into their own separate polygons. 446 | select (ST_DumpRings(geom)).geom from exploded 447 | ) select 448 | -- Finally, build the multipolygon back up using only the rings 449 | -- that are larger than the specified threshold area. 450 | ST_SetSRID(ST_BuildArea(ST_Collect(geom)), ST_SRID(g)) 451 | from rings 452 | where ST_Area(geom) > area_threshold; 453 | $func$; 454 | 455 | create or replace function Sieve (g geometry, area_threshold integer) 456 | returns geometry 457 | language sql immutable as 458 | $func$ 459 | with exploded as ( 460 | -- First use ST_Dump to explode the input multipolygon 461 | -- to individual polygons. 462 | select (ST_Dump(g)).geom 463 | ), rings as ( 464 | -- Next use ST_DumpRings to turn all of the inner and outer rings 465 | -- into their own separate polygons. 466 | select (ST_DumpRings(geom)).geom from exploded 467 | ) select 468 | -- Finally, build the multipolygon back up using only the rings 469 | -- that are larger than the specified threshold area. 470 | ST_SetSRID(ST_BuildArea(ST_Collect(geom)), ST_SRID(g)) 471 | from rings 472 | where ST_Area(geom) > area_threshold; 473 | $func$; 474 | 475 | 476 | /****************************************************************************** 477 | ### SmartShrink ### 478 | 479 | Buffers a polygon progressively (on an exponential scale) until the 480 | area of the result hits a certain threshold ratio to the original area. 481 | The result is also simplified with a tolerance matching the inset 482 | distance. 483 | 484 | __Parameters:__ 485 | 486 | - `geometry` g - A (multi)polygon. 487 | - `float` ratio - The threshold for how much smaller (by area) you want 488 | the shrunk polygon to be compared to the original. Eg a value of 0.6 489 | would result in a polygon that is at least 60% as large as the input. 490 | - `boolean` simplify - Defaults to false. Whether or not you would 491 | like the shrunk geometry simplified. 492 | 493 | __Returns:__ `geometry` 494 | ******************************************************************************/ 495 | create or replace function SmartShrink( 496 | geom geometry, 497 | ratio float, 498 | simplify boolean = false 499 | ) 500 | returns geometry 501 | language plpgsql immutable as 502 | $func$ 503 | declare 504 | full_area float := ST_Area(geom); 505 | buf0 geometry; 506 | buf1 geometry := geom; 507 | d0 float := 0; 508 | d1 float := 2; 509 | begin 510 | while ST_Area(buf1) > (full_area * ratio) loop 511 | d0 := d1; 512 | d1 := d1 * 2; 513 | buf0 := buf1; 514 | buf1 := ST_Buffer(geom, -d1, 'quad_segs=0'); 515 | end loop; 516 | if simplify = true then 517 | return ST_SimplifyPreserveTopology(buf0, d0); 518 | else 519 | return buf0; 520 | end if; 521 | end; 522 | $func$; 523 | 524 | 525 | /****************************************************************************** 526 | ### TileBBox ### 527 | 528 | Given a Web Mercator tile ID as (z, x, y), returns a bounding-box 529 | geometry of the area covered by that tile. 530 | 531 | __Parameters:__ 532 | 533 | - `integer` z - A tile zoom level. 534 | - `integer` x - A tile x-position. 535 | - `integer` y - A tile y-position. 536 | - `integer` srid - SRID of the desired target projection of the bounding 537 | box. Defaults to 3857 (Web Mercator). 538 | 539 | __Returns:__ `geometry(polygon)` 540 | ******************************************************************************/ 541 | create or replace function TileBBox (z int, x int, y int, srid int = 3857) 542 | returns geometry 543 | language plpgsql immutable as 544 | $func$ 545 | declare 546 | max numeric := 20037508.34; 547 | res numeric := (max*2)/(2^z); 548 | bbox geometry; 549 | begin 550 | bbox := ST_MakeEnvelope( 551 | -max + (x * res), 552 | max - (y * res), 553 | -max + (x * res) + res, 554 | max - (y * res) - res, 555 | 3857 556 | ); 557 | if srid = 3857 then 558 | return bbox; 559 | else 560 | return ST_Transform(bbox, srid); 561 | end if; 562 | end; 563 | $func$; 564 | 565 | 566 | /****************************************************************************** 567 | ### ToPoint ### 568 | 569 | Helper to wrap ST_PointOnSurface, ST_MakeValid. This is needed because 570 | of a ST_PointOnSurface bug in geos < 3.3.8 where POLYGON EMPTY can pass 571 | through as a polygon geometry. 572 | If the input geometry is a polygon with less than 5 points the ST_Centroid 573 | of the polygon will be used instead of ST_PointOnSurface to speed up calculation. 574 | 575 | __Parameters:__ 576 | 577 | - `geometry` g - A geometry. 578 | 579 | __Returns:__ `geometry(point)` 580 | 581 | __Example:__ 582 | 583 | ```sql 584 | -- Create an additional point geometry colums for labeling 585 | ALTER TABLE city_park ADD COLUMN geom_label geometry(point); 586 | UPDATE city_park SET geom_label = ToPoint(geom); 587 | ``` 588 | ******************************************************************************/ 589 | create or replace function ToPoint (g geometry) 590 | returns geometry(point) 591 | language plpgsql immutable as 592 | $func$ 593 | begin 594 | g := ST_MakeValid(g); 595 | if GeometryType(g) = 'POINT' then 596 | return g; 597 | elsif ST_IsEmpty(g) then 598 | -- This should not be necessary with Geos >= 3.3.7, but we're getting 599 | -- mystery MultiPoint objects from ST_MakeValid (or somewhere) when 600 | -- empty objects are input. 601 | return null; 602 | elsif (GeometryType(g) = 'POLYGON' OR GeometryType(g) = 'MULTIPOLYGON') and ST_NPoints(g) <= 5 then 603 | -- For simple polygons the centroid is good enough for label placement 604 | return ST_Centroid(g); 605 | else 606 | return ST_PointOnSurface(g); 607 | end if; 608 | end; 609 | $func$; 610 | 611 | 612 | /****************************************************************************** 613 | ### ZRES ### 614 | 615 | Takes a web mercator zoom level and returns the pixel resolution for that 616 | scale, assuming 256x256 pixel tiles. Non-integer zoom levels are accepted. 617 | 618 | __Parameters:__ 619 | 620 | - `integer` or `float` z - A Web Mercator zoom level. 621 | 622 | __Returns:__ `float` 623 | 624 | __Examples:__ 625 | 626 | ```sql 627 | -- Delete all polygons smaller than 1px square at zoom level 10 628 | DELETE FROM water_polygons WHERE sqrt(ST_Area(geom)) < ZRes(10); 629 | 630 | -- Simplify geometries to a resolution appropriate for zoom level 10 631 | UPDATE water_polygons SET geom = ST_Simplify(geom, ZRes(10)); 632 | ``` 633 | ******************************************************************************/ 634 | create or replace function ZRes (z integer) 635 | returns float 636 | returns null on null input 637 | language sql immutable as 638 | $func$ 639 | select (40075016.6855785/(256*2^z)); 640 | $func$; 641 | 642 | create or replace function ZRes (z float) 643 | returns float 644 | returns null on null input 645 | language sql immutable as 646 | $func$ 647 | select (40075016.6855785/(256*2^z)); 648 | $func$; 649 | 650 | 651 | /****************************************************************************** 652 | ### Z ### 653 | 654 | Returns a Web Mercator integer zoom level given a scale denominator. 655 | 656 | Useful with Mapnik's !scale_denominator! token in vector tile source 657 | queries. 658 | 659 | __Parameters:__ 660 | 661 | - `numeric` scale_denominator - The denominator of the scale, eg `250000` 662 | for a 1:250,000 scale. 663 | 664 | __Returns:__ `integer` 665 | 666 | __Example Mapbox Studio query:__ 667 | 668 | ```sql 669 | ( SELECT * FROM roads 670 | WHERE Z(!scale_denominator!) >= 12 671 | ) AS data 672 | ``` 673 | ******************************************************************************/ 674 | create or replace function z (numeric) 675 | returns integer 676 | language sql 677 | immutable 678 | returns null on null input 679 | as $func$ 680 | select 681 | case 682 | -- Don't bother if the scale is larger than ~zoom level 0 683 | when $1 > 600000000 or $1 = 0 then null 684 | else cast (round(log(2,559082264.028/$1)) as integer) 685 | end; 686 | $func$; 687 | 688 | 689 | --------------------------------------------------------------------------------