├── README.md ├── _config.yml ├── lines ├── index.md ├── line.md ├── network.md └── trajectory.md ├── overlay ├── difference.md ├── index.md ├── intersection.md ├── lines.md ├── noding.md ├── overlay.md ├── split.md └── union.md ├── pgp-OLD-lines.md ├── pgp-OLD-overlay.md ├── pgp-OLD-process.md ├── pgp-OLD-query.md ├── pgp-antipattern.md ├── pgp-clean.md ├── pgp-coverage.md ├── pgp-create.md ├── pgp-geography.md ├── pgp-group.md ├── pgp-intro.md ├── pgp-io.md ├── pgp-measure.md ├── pgp-transform.md ├── pgp-updel.md ├── process ├── buffer.md ├── conflation.md ├── construct.md ├── hull.md ├── index.md ├── point-dist.md ├── polygonize.md └── surface.md └── query ├── index.md ├── query-distance.md ├── query-index.md ├── query-lines.md ├── query-nn.md ├── query-pip.md ├── query-shape-valid.md ├── query-spatial-rel.md └── query-stat.md /README.md: -------------------------------------------------------------------------------- 1 | --- 2 | nav_exclude: true 3 | --- 4 | 5 | # PostGIS Patterns 6 | 7 | A compendium of useful PostGIS problems, patterns, and solutions. 8 | 9 | See the [website](https://dr-jts.github.io/postgis-patterns/pgp-intro.html). 10 | 11 | 12 | 13 | 14 | -------------------------------------------------------------------------------- /_config.yml: -------------------------------------------------------------------------------- 1 | # theme: jekyll-theme-cayman 2 | remote_theme: pmarsceill/just-the-docs 3 | -------------------------------------------------------------------------------- /lines/index.md: -------------------------------------------------------------------------------- 1 | --- 2 | has_children: true 3 | --- 4 | 5 | # Lines and Networks 6 | -------------------------------------------------------------------------------- /lines/line.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Lines and Networks 3 | --- 4 | 5 | # Line Processing 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Angles 12 | 13 | ### Compute Angle at which Two Lines Intersect 14 | 15 | 16 | ### Compute Azimuth at a Point on a Line 17 | 18 | 19 | Solution 20 | Would be nice to have a ST_SegmentIndex function to get the index of the segment nearest to a point. Then this becomes simple. 21 | 22 | ### Create Line Segment with specified angle 23 | 24 | 25 | 26 | ## Distance 27 | 28 | ### Compute Perpendicular Distance to a Baseline (AKA “Width” of a curve) 29 | 30 | 31 | ### Measure Length of every LineString segment 32 | 33 | Solution 34 | Use CROSS JOIN LATERAL with generate_series and ST_MakeLine, ST_Length 35 | ST_DumpSegments would make this much easier! 36 | 37 | ## Line Metrics 38 | 39 | ### Sinuosity of a Line 40 | 41 | 42 | 43 | ## Inserting Vertices into Lines 44 | 45 | ### Find Segment of Line Closest to Point to allow Point Insertion 46 | 47 | 48 | Currently requires iteration. 49 | Would be nice if the Linear Referencing functions could return segment index. 50 | See 51 | 52 | ```sql 53 | CREATE OR REPLACE FUNCTION ST_LineLocateN( line geometry, pt geometry ) 54 | RETURNS integer 55 | AS $$ 56 | SELECT i FROM ( 57 | SELECT i, ST_Distance( 58 | ST_MakeLine( ST_PointN( line, s.i ), ST_PointN( line, s.i+1 ) ), 59 | pt) AS dist 60 | FROM generate_series(1, ST_NumPoints( line )-1) AS s(i) 61 | ORDER BY dist 62 | ) AS t LIMIT 1; 63 | $$ 64 | LANGUAGE sql STABLE STRICT; 65 | ``` 66 | ### Insert LineString Vertices at Closest Point(s) 67 | 68 | 69 | 70 | 71 | ST_Snap does this nicely 72 | ```sql 73 | SELECT ST_AsText( ST_Snap('LINESTRING (0 0, 9 9, 20 20)', 74 | 'MULTIPOINT( (1 1.1), (12 11.9) )', 0.2)); 75 | ``` 76 | 77 | ### Add intersection points between sets of Lines (AKA Noding) 78 | 79 | Problem 80 | Add nodes into a road network from access side roads 81 | 82 | Solutions 83 | One post recommends simply unioning (overlaying) all the linework. This was accepted, but has obvious problems: 84 | Hard to extract just the road network lines 85 | If side road falls slightly short will not create a node 86 | 87 | ## Extracting Vertices from Lines 88 | 89 | ### Select every Nth point from a LineString 90 | 91 | 92 | ### Construct evenly-spaced points along a polygon boundary 93 | 94 | 95 | ![](https://i.stack.imgur.com/XFfYE.png) 96 | 97 | Note that the point count needs to be substituted in two places in the following query: 98 | ```sql 99 | WITH shell AS ( 100 | SELECT ST_ExteriorRing('POLYGON ((5 5, 10 15, 17 10, 5 5))') geom 101 | ) 102 | SELECT i, ST_LineInterpolatePoint(geom, (i-1.0)/40) pt 103 | FROM shell 104 | JOIN generate_series (1, 40) AS step(i) ON true; 105 | ``` 106 | 107 | ## Extracting Segments from Lines 108 | 109 | ### Extract Segments from LineStrings 110 | 111 | 112 | #### Using `ST_DumpSegents` 113 | In PostGIS 3.2 this can be done with `ST_DumpSegments`: 114 | ```sql 115 | WITH data(geom) AS (VALUES 116 | ('LINESTRING (1 1, 3 1, 5 2, 7 1, 9 1, 9 3)'::geometry), 117 | ('LINESTRING (1 5, 5 6, 9 5)'::geometry) 118 | ) 119 | SELECT ST_AsText( (ST_DumpSegments( data.geom )).geom ) AS seg 120 | FROM data; 121 | ``` 122 | 123 | #### Using LATERAL JOIN with `generate_series` 124 | This can be done in SQL using an implicit `LATERAL JOIN` against two `generate_series` calls 125 | on the number of line elements and the number of vertices in each line: 126 | ```sql 127 | WITH data(id, geom) AS (VALUES 128 | (1, 'LINESTRING (1 1, 2 2, 3 3, 4 4)'::geometry), 129 | (2, 'LINESTRING (0 1, 0 2, 0 3, 0 4)'::geometry) 130 | ) 131 | SELECT id, ST_AsText( ST_MakeLine(ST_PointN(geom, i-1), ST_PointN(geom, i))) AS seg 132 | FROM data 133 | CROSS JOIN generate_series(2, ST_NumPoints(data.geom)) AS i; 134 | ``` 135 | 136 | #### Using `ST_Dump` and `LEAD` window function 137 | 138 | ```sql 139 | WITH data(id, geom) AS (VALUES 140 | (1, 'LINESTRING (1 1, 2 2, 3 3, 4 4)'::geometry), 141 | (2, 'LINESTRING (0 1, 0 2, 0 3, 0 4)'::geometry) 142 | ) 143 | SELECT * FROM (SELECT id, ST_AsText( ST_MakeLine(dmp.geom, LEAD(dmp.geom) OVER(PARTITION BY id ORDER BY dmp.path))) AS seg 144 | FROM data 145 | CROSS JOIN LATERAL ST_DumpPoints(geom) AS dmp) AS t 146 | WHERE seg IS NOT NULL; 147 | ``` 148 | 149 | ### Extract Segments from MultiLineStrings 150 | 151 | #### Using `ST_DumpSegents` 152 | In PostGIS 3.2 this can be done with `ST_DumpSegments`: 153 | ```sql 154 | WITH data(geom) AS (VALUES 155 | ('MULTILINESTRING ((1 1, 3 1, 5 2, 7 1, 9 1, 9 3), (1 3, 3 3, 5 4, 7 3))'::geometry), 156 | ('MULTILINESTRING ((1 5, 5 6, 9 5), (1 6, 5 7, 9 6))'::geometry) 157 | ) 158 | SELECT ST_AsText( (ST_DumpSegments( data.geom )).geom ) AS seg 159 | FROM data; 160 | ``` 161 | 162 | #### Using LATERAL JOIN with `generate_series` 163 | This can be done in SQL using an implicit `LATERAL JOIN` against two `generate_series` calls 164 | on the number of line elements and the number of vertices in each line: 165 | ```sql 166 | WITH data(geom) AS (VALUES 167 | ('MULTILINESTRING ((1 1, 3 1, 5 2, 7 1, 9 1, 9 3), (1 3, 3 3, 5 4, 7 3))'::geometry), 168 | ('MULTILINESTRING ((1 5, 5 6, 9 5), (1 6, 5 7, 9 6))'::geometry) 169 | ) 170 | SELECT ST_MakeLine(ST_PointN(line, j-1), ST_PointN(line, j)) AS seg 171 | FROM (SELECT ST_GeometryN(geom, i) AS line 172 | FROM data, 173 | generate_series(1, ST_NumGeometries(data.geom)) AS i) AS t, 174 | generate_series(2, ST_NumPoints(t.line)) AS j; 175 | ``` 176 | 177 | 178 | ## Interpolating Lines 179 | 180 | ### Construct Line substring containing a set of Points 181 | 182 | 183 | ![](https://i.stack.imgur.com/LtZM0.png) 184 | 185 | **Solution 1 - Extract subline with new endpoints** 186 | * use `ST_LineLocatePoint()` on each intersection point to get the fraction of the point on the line 187 | * use `ST_LineSubstring(my_line.geom, min(fraction), max(fraction))` with a GROUP BY on the line id to get subline 188 | 189 | **Solution 2 - Extract subline with all points added** 190 | 191 | Comment: this probably only works for a single line and using all points in a table. 192 | 193 | ```sql 194 | SELECT id, ST_Makeline(geom) AS geom 195 | FROM ( 196 | SELECT lns.id, 197 | ST_LineSubstring( 198 | ln.geom, 199 | ST_LineLocatePoint(ln.geom, pts.geom), 200 | ST_LineLocatePoint(ln.geom, LEAD(pts.geom) OVER(ORDER BY pts.id)) 201 | ) AS geom 202 | FROM AS ln 203 | CROSS JOIN 204 | AS pts 205 | ) q 206 | WHERE geom IS NOT NULL 207 | GROUP BY id; 208 | ``` 209 | 210 | 211 | ## Extrapolating Lines 212 | 213 | ### Extrapolate a Line 214 | 215 | 216 | Also: 217 | 218 | ![](https://i.stack.imgur.com/FTMi3.png) 219 | 220 | ### Extending a straight Line 221 | 222 | 223 | Extend a line between two points by a given amount (1 m) at both ends. 224 | 225 | **Solution** 226 | ```sql 227 | WITH data AS ( SELECT ST_MakeLine(ST_Point(1,2), ST_Point(3,4)) AS geom ) 228 | SELECT ST_AsText( ST_MakeLine( 229 | ST_Translate(b, sin(azBA) * len, cos(azBA) * len), 230 | ST_Translate(a, sin(azAB) * len, cos(azAB) * len)) ) 231 | FROM ( 232 | SELECT a, b, 233 | ST_Azimuth(a, b) AS azAB, ST_Azimuth(b, a) AS azBA, 234 | ST_Distance(a, b) + len_extend AS len 235 | FROM ( 236 | SELECT ST_StartPoint(geom) AS a, ST_EndPoint(geom) AS b, 1.0 as len_extend 237 | FROM data 238 | ) AS sub 239 | ) AS sub2; 240 | ``` 241 | 242 | ### PostGIS Ideas 243 | `ST_LineSubstring` could be enhanced to allow fractions outside [0,1]. 244 | Or make a new function `ST_LineExtend` (which should also handle shortening the line). 245 | 246 | ### Extend a LineString to the boundary of a polygon 247 | 248 | 249 | ![](https://i.stack.imgur.com/zvKKx.png) 250 | 251 | **PostGIS Idea** 252 | Create a new function `ST_LineExtract(line, index1, index2)` to extract a portion of a LineString between two vertex indices 253 | 254 | ### Extrapolate a Line to opposite side of Polygon 255 | 256 | 257 | Given a point in a polygon and a point outside the polygon, find the point on the opposite side of the polygon lying on the line between them. 258 | 259 | ![](https://i.stack.imgur.com/WyYuO.png) 260 | 261 | **Solution** 262 | 263 | 264 | ```sql 265 | WITH 266 | radius AS (SELECT ST_MakeLine( pt.geom, ST_Centroid(poly.geom) ) AS geom FROM pnt pt, polygon poly), 267 | asilen AS (SELECT ST_Azimuth(ST_StartPoint(geom), ST_EndPoint(geom)) AS azimuth, 268 | ST_Distance(ST_StartPoint(geom), ST_EndPoint(geom)) + 0.00001 AS length FROM radius), 269 | tblc AS (SELECT ST_MakeLine(a.geom, ST_Translate(a.geom, sin(azimuth)*length, cos(azimuth)*length)) geom FROM radius a, asilen b), 270 | tbld AS (SELECT ST_Intersection(a.geom, ST_ExteriorRing(b.geom)) geom FROM tblc a JOIN polygon b ON ST_Intersects(a.geom, b.geom)), 271 | all_pts AS (SELECT (ST_Dump(geom)).geom geom FROM tbld) 272 | SELECT (all_pts.geom) geom, ST_Distance(all_pts.geom, radius.geom) dist 273 | FROM all_pts, radius 274 | ORDER BY dist DESC LIMIT 1; 275 | ``` 276 | 277 | ### Find Intersection point of disjoint Lines 278 | 279 | 280 | ![](https://i.stack.imgur.com/DEUn7.png) 281 | 282 | **Solution** 283 | Extend both lines so that they intersect, then compute intersection point. 284 | 285 | ```sql 286 | WITH segments AS ( 287 | SELECT ST_StartPoint('LINESTRING (4.505476754241158 51.92221504789901, 4.505379267847784 51.92221833721103)') AS s1_a, 288 | ST_EndPoint( 'LINESTRING (4.505476754241158 51.92221504789901, 4.505379267847784 51.92221833721103)') AS s1_b, 289 | 290 | ST_StartPoint('LINESTRING (4.50554487780521 51.922119943633575, 4.504656820078167 51.92231795217855)') AS s2_a, 291 | ST_EndPoint(. 'LINESTRING (4.50554487780521 51.922119943633575, 4.504656820078167 51.92231795217855)') AS s2_b 292 | ) 293 | ,azimuths AS ( SELECT *, 294 | ST_Azimuth(s1_a, s1_b) AS s1_az1, 295 | ST_Azimuth(s1_b, s1_a) AS s1_az2, 1 AS s1_len, 296 | ST_Azimuth(s2_a, s2_b) AS s2_az1, 297 | ST_Azimuth(s2_b, s2_a) AS s2_az2, 1 AS s2_len 298 | FROM segments 299 | ) 300 | SELECT ST_Intersection( 301 | ST_MakeLine( ST_Translate(s1_b, sin(s1_az1) * s1_len, cos(s1_az1) * s1_len), 302 | ST_Translate(s1_a, sin(s1_az2) * s1_len, cos(s1_az2) * s1_len) ), 303 | ST_MakeLine( ST_Translate(s2_b, sin(s2_az1) * s2_len, cos(s2_az1) * s2_len), 304 | ST_Translate(s2_a, sin(s2_az2) * s2_len, cos(s2_az2) * s2_len) ) 305 | ) 306 | FROM azimuths; 307 | ``` 308 | 309 | ## Splitting Lines 310 | 311 | ### Remove Longest Segment from a LineString 312 | 313 | 314 | Solution (part) 315 | Remove longest segment, splitting linestring into two parts if needed. 316 | 317 | Useful patterns in this code: 318 | 319 | JOIN LATERAL generate_series to extract the line segments 320 | array slicing to extract a subline containing a section of the original line 321 | 322 | It would be clearer if parts of this SQL were wrapped in functions (e.g. an `ST_LineSlice` function, and a `ST_DumpSegments` function - which should become part of PostGIS). 323 | ```sql 324 | WITH data(id, geom) AS (VALUES 325 | ( 1, 'LINESTRING (0 0, 1 1, 2.1 2, 3 3, 4 4)'::geometry ) 326 | ), 327 | longest AS (SELECT i AS iLongest, geom, 328 | ST_Distance( ST_PointN( data.geom, s.i ), 329 | ST_PointN( data.geom, s.i+1 ) ) AS dist 330 | FROM data JOIN LATERAL ( 331 | SELECT i FROM generate_series(1, ST_NumPoints( data.geom )-1) AS gs(i) 332 | ) AS s(i) ON true 333 | ORDER BY dist LIMIT 1 334 | ) 335 | SELECT 336 | CASE WHEN iLongest > 2 THEN ST_AsText( ST_MakeLine( 337 | (ARRAY( SELECT (ST_DumpPoints(geom)).geom FROM longest))[1 : iLongest - 1] 338 | )) ELSE null END AS line1, 339 | CASE WHEN iLongest < ST_NumPoints(geom) - 1 THEN ST_AsText( ST_MakeLine( 340 | (ARRAY( SELECT (ST_DumpPoints(geom)).geom FROM longest))[iLongest + 1: ST_NumPoints(geom)] 341 | )) ELSE null END AS line2 342 | FROM longest; 343 | ``` 344 | 345 | ### Split Lines into sections of given length 346 | 347 | 348 | Modern solution using LATERAL: 349 | ```sql 350 | WITH data AS ( 351 | SELECT * FROM (VALUES 352 | ( 'A', 'LINESTRING( 0 0, 200 0)'::geometry ), 353 | ( 'B', 'LINESTRING( 0 100, 350 100)'::geometry ), 354 | ( 'C', 'LINESTRING( 0 200, 50 200)'::geometry ) 355 | ) AS t(id, geom) 356 | ) 357 | SELECT id, i, ST_AsText( ST_LineSubstring( d.geom, substart, LEAST(subend, 1) )) AS geom 358 | FROM (SELECT id, geom, ST_Length(geom) len, 100 sublen FROM data) AS d 359 | CROSS JOIN LATERAL ( 360 | SELECT i, 361 | (sublen * i)/len AS substart, 362 | (sublen * (i+1)) / len AS subend 363 | FROM generate_series(0, floor( d.len / sublen )::integer ) AS t(i) 364 | -- skip last i if line length is exact multiple of sublen 365 | WHERE (sublen * i)/len <> 1.0 366 | ) AS d2; 367 | ``` 368 | 369 | **See also** 370 | 371 | 372 | 373 | This one contains a utility function to segment a line by **length**, by using `ST_LineSubstring`. Possible candidate for inclusion? 374 | 375 | 376 | 377 | ### Split Lines by Points 378 | 379 | 380 | 381 | **Solution 1 - `ST_Snap` and `ST_Split`** 382 | * Use `ST_Snap` to snap line to point(s) to ensure points are in line 383 | * Use `ST_Split` to split line at points 384 | 385 | ```sql 386 | WITH data AS (SELECT 387 | 'LINESTRING(0 0, 100 100)'::geometry AS line, 388 | 'POINT(51 50)':: geometry AS point 389 | ) 390 | SELECT ST_AsText( ST_Split( ST_Snap(line, point, 1), point)) AS split 391 | FROM data; 392 | ``` 393 | 394 | **Solution 2 - `ST_LineLocatePoint` and `ST_LineSubstring`** 395 | ```sql 396 | WITH 397 | data(_input, _blade) AS ( 398 | VALUES ( 399 | 'SRID=3857;LINESTRING(6050668.141401841 3747562.695792065, 6050847.281693009 3748099.9265132365, 6051307.630580775 3747871.7845201474)'::GEOMETRY, 400 | 'SRID=3857;POINT(6050714.928364518 3747735.4091125955)'::GEOMETRY 401 | ) 402 | ) 403 | SELECT 404 | ST_LineSubstring(_input, 0, ST_LineLocatePoint(_input, _blade)) AS part1, 405 | ST_LineSubstring(_input, ST_LineLocatePoint(_input, _blade), 1) AS part2 406 | FROM data; 407 | ``` 408 | 409 | ## Merging Lines 410 | 411 | ### Merge lines that touch at endpoints 412 | 413 | 414 | ![](https://i.stack.imgur.com/dCCQZ.jpg) 415 | 416 | Solution given uses `ST_ClusterWithin`. Can be improved slightly (e.g. can use `ST_Boundary` to get endpoints?). Would be nicer if `ST_ClusterWithin` was a window function. 417 | 418 | Could also use a recursive query to do a transitive closure of the “touches at endpoints” condition. This would be a nice example, and would scale better. 419 | 420 | Can also use `ST_LineMerge` to do this: 421 | 422 | ```sql 423 | WITH data(geom) AS (VALUES 424 | ('LINESTRING (0 0, 1 1)'), 425 | ('LINESTRING (2 2, 1 1)'), 426 | ('LINESTRING (7 3, 0 0)'), 427 | ('LINESTRING (2 4, 2 3)'), 428 | ('LINESTRING (3 8, 1 5)'), 429 | ('LINESTRING (1 5, 2 5)'), 430 | ('LINESTRING (7 3, 0 7)') 431 | ), 432 | merged AS ( 433 | SELECT (ST_Dump(ST_LineMerge(ST_Collect(geom)))).geom 434 | FROM data 435 | ) 436 | SELECT row_number() OVER () AS cid, 437 | geom 438 | FROM merged; 439 | ``` 440 | 441 | #### See Also 442 | 443 | 444 | ```sql 445 | WITH data(geom) AS (VALUES 446 | ( 'LINESTRING (50 50, 150 100, 250 75)'::geometry ) 447 | ,( 'LINESTRING (250 75, 200 0, 130 30, 100 150)'::geometry ) 448 | ,( 'LINESTRING (100 150, 130 170, 220 190, 290 190)'::geometry ) 449 | ) 450 | SELECT ST_AsText(ST_LineMerge(ST_Collect(geom))) AS line 451 | FROM data; 452 | ``` 453 | ### Merge lines that touch at endpoints 2 454 | 455 | 456 | **Solution** 457 | 458 | 459 | ### Connect Lines that do not touch 460 | 461 | 462 | ![](https://i.stack.imgur.com/ng4fX.png) 463 | 464 | **Solution** 465 | No built-in function to do this, but post provides a custom function. 466 | 467 | ```sql 468 | CREATE OR REPLACE FUNCTION public.st_mergecloselines( 469 | geometry, geometry) 470 | RETURNS geometry 471 | LANGUAGE 'sql' 472 | -- This function merge two lines that don't within (dont touching) returing a single multiline. By Emilson Ribeiro Neto - emilsonribeiro@hotmail.com 473 | AS $BODY$ 474 | 475 | select ST_LineMerge(st_union(st_union($1, 476 | (case 477 | WHEN (st_distanceSphere(ST_StartPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_StartPoint($1),ST_EndPoint($2)) 478 | and (st_distanceSphere(ST_StartPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_EndPoint($1),ST_StartPoint($2))) 479 | and (st_distanceSphere(ST_StartPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_EndPoint($1),ST_EndPoint($2))) 480 | ) THEN st_makeLine(ST_StartPoint($1),ST_StartPoint($2)) 481 | 482 | WHEN (st_distanceSphere(ST_EndPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_StartPoint($1),ST_EndPoint($2)) 483 | and (st_distanceSphere(ST_EndPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_StartPoint($1),ST_StartPoint($2))) 484 | and (st_distanceSphere(ST_EndPoint($1),ST_StartPoint($2)) < st_distanceSphere(ST_EndPoint($1),ST_EndPoint($2))) 485 | ) THEN st_makeLine(ST_EndPoint($1),ST_StartPoint($2)) 486 | 487 | WHEN (st_distanceSphere(ST_StartPoint($1),ST_EndPoint($2)) < st_distanceSphere(ST_StartPoint($1),ST_StartPoint($2)) 488 | and (st_distanceSphere(ST_StartPoint($1),ST_EndPoint($2)) < st_distanceSphere(ST_EndPoint($1),ST_StartPoint($2))) 489 | and (st_distanceSphere(ST_StartPoint($1),ST_EndPoint($2)) < st_distanceSphere(ST_EndPoint($1),ST_EndPoint($2))) 490 | ) THEN st_makeLine(ST_StartPoint($1),ST_EndPoint($2)) 491 | else st_makeLine(ST_EndPoint($1),ST_EndPoint($2)) 492 | end)),$2)) 493 | 494 | $BODY$ 495 | ``` 496 | -------------------------------------------------------------------------------- /lines/network.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Lines and Networks 3 | --- 4 | 5 | # Networks 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Find Diameter (Longest Path) of Network 12 | 13 | 14 | 15 | 16 | 17 | 18 | ![](https://i.stack.imgur.com/lLqqW.jpg) 19 | 20 | ### PostGIS Idea 21 | Input Parameters: MultiLineString 22 | 23 | Start and End point could be snapped to nearest endpoints if not already in network 24 | Maybe also function to snap a network? 25 | 26 | “Longest Shortest Path” - AKA Diameter of a Graph 27 | 28 | **Algorithm** 29 | * Pick an endpoint 30 | * Find furthest vertex (longest shortest path over all other vertices) 31 | * Take that vertex, and find longest shortest path to all other vertices) 32 | 33 | ## Find overshoots in Network 34 | 35 | 36 | Find overshoots in a set of LineStrings forming a network. 37 | Equivalent to finding all crossing pairs of lines. 38 | 39 | ![](https://i.stack.imgur.com/8d2Ab.png) 40 | 41 | **Solution** 42 | 43 | Use`ST_Crosses` on all intersecting pairs of lines. 44 | Use a [triangle join](https://www.sqlservercentral.com/articles/hidden-rbar-triangular-joins) to ensure checking each pair only once. 45 | Indexes on `id` and geometry` should be used. 46 | 47 | ``` 48 | WITH data(id, geom) AS (VALUES 49 | (1,ST_GeomFromText('MULTILINESTRING((136.63964778201967 36.58031552554121,136.64078637948796 36.57968013023401,136.6414207216891 36.579313967665655,136.64203092428795 36.578959650067986,136.6428838673968 36.57843301697034,136.6438347098042 36.577844992552514))', 4326)), 50 | (2,ST_GeomFromText('MULTILINESTRING((136.64039880046448 36.57933335255234,136.64078637948796 36.57968013023401,136.64119407544638 36.580076445271914,136.64165541506554 36.58051798901414))', 4326)), 51 | (3,ST_GeomFromText('MULTILINESTRING((136.64039880046448 36.57933335255234,136.64044439789086 36.578869185464725))', 4326)), 52 | (4,ST_GeomFromText('MULTILINESTRING((136.6409003730539 36.57873995108804,136.6414207216891 36.579313967665655,136.64222404380473 36.580108753416425))', 4326)), 53 | (5,ST_GeomFromText('MULTILINESTRING((136.6416232292288 36.57843409435816,136.64203092428795 36.578959650067986))', 4326)), 54 | (6,ST_GeomFromText('MULTILINESTRING((136.64203092428795 36.578959650067986,136.64244666738 36.57935489221467,136.64283290461503 36.57974259264671))', 4326)), 55 | (7,ST_GeomFromText('MULTILINESTRING((136.64250969906357 36.57802376968141,136.6428838673968 36.57843301697034,136.64326608196427 36.578854108330574))', 4326)), 56 | (8,ST_GeomFromText('MULTILINESTRING((136.64364829653186 36.577513284810436,136.6438347098042 36.577844992552514))', 4326)), 57 | (9,ST_GeomFromText('MULTILINESTRING((136.6438347098042 36.577844992552514,136.64412438862985 36.57833070559775))', 4326)) 58 | ) 59 | SELECT a.id, b.id, ST_Intersection(a.geom, b.geom) AS geom 60 | FROM data a 61 | JOIN data b ON ST_Intersects(a.geom, b.geom) 62 | WHERE a.id < b.id AND ST_Crosses(a.geom, b.geom); 63 | ``` 64 | 65 | 66 | ## Minimum Spanning Tree of a set of Points 67 | 68 | 69 | **Prim's Algorithm** 70 | 71 | Recursive query using: 72 | * **vertices** - current set of vertices in tree 73 | * **edge** - the last edge added to the tree 74 | * **ids** - the IDs of the vertices in the tree (allows choosing a vertex not in the tree) 75 | 76 | The algorithm works by choosing an unused point as the next vertex to add, 77 | and connecting it to the tree by the shortest line. 78 | 79 | ```sql 80 | WITH RECURSIVE 81 | graph AS ( 82 | SELECT dmp.path[1] AS id, dmp.geom 83 | FROM ST_Dump('MULTIPOINT ((20 20), (20 60), (40 50), (70 30), (80 70), (50 90), (30 90))'::GEOMETRY) AS dmp 84 | ), 85 | tree AS ( 86 | SELECT g.geom::GEOMETRY AS vertices, 87 | ARRAY[g.id] AS ids, 88 | NULL::GEOMETRY AS edge 89 | FROM graph AS g 90 | WHERE id = 1 91 | UNION ALL 92 | SELECT ST_Union(t.vertices, v.geom), 93 | t.ids || v.id, 94 | ST_ShortestLine(t.vertices, v.geom) 95 | FROM tree AS t 96 | CROSS JOIN LATERAL ( 97 | SELECT g.id, g.geom 98 | FROM graph AS g 99 | WHERE NOT g.id = ANY(t.ids) 100 | ORDER BY t.vertices <-> g.geom 101 | LIMIT 1 102 | ) AS v 103 | ) 104 | SELECT edge FROM tree WHERE edge IS NOT NULL; 105 | ``` 106 | 107 | ## Minimum Spanning Tree 108 | 109 | 110 | ![](https://i.stack.imgur.com/oqALq.png) 111 | 112 | SQL [functions](https://gist.github.com/andrewxhill/13de0618d31893cdc4c5) to compute a Minimum Spanning Tree. 113 | 114 | ## Seaway Distances & Routes 115 | 116 | ![](https://www.ausvet.com.au/wp-content/uploads/Blog_images/seaway_1.png) 117 | 118 | ## Find isolated Network edges (1) 119 | 120 | 121 | ![](https://i.stack.imgur.com/jx85n.png) 122 | 123 | ```sql 124 | SELECT l1.id 125 | FROM links l1 126 | WHERE NOT EXISTS 127 | (SELECT 1 128 | FROM links l2 129 | WHERE l1.id != l2.id 130 | AND ST_INTERSECTS(l1.geom, l2.geom) 131 | ); 132 | ``` 133 | 134 | ## Find isolated Network edges (2) 135 | 136 | 137 | ![](https://i.stack.imgur.com/1eoWm.jpg) 138 | 139 | 140 | -------------------------------------------------------------------------------- /lines/trajectory.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Lines and Networks 3 | --- 4 | 5 | # Temporal Trajectories 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Find Coincident Paths 12 | 13 | 14 | ![](https://www.cybertec-postgresql.com/wp-content/uploads/2020/04/GPS-Tracking5.jpg) 15 | 16 | ## Remove Stationary Points 17 | 18 | 19 | ## Find Path durations within Polygons 20 | 21 | 22 | Given: 23 | * a table of points along GPS tracks 24 | * a table of polygons 25 | 26 | Finds the path duration within each polygon. 27 | 28 | ```sql 29 | WITH trajectory AS ( 30 | SELECT track, 31 | ST_SetSRID(ST_MakeLine(ST_MakePointM(ST_X(geom), ST_Y(geom), EXTRACT(EPOCH FROM ts)) ORDER BY ts),4326) AS geom 32 | FROM gps 33 | GROUP BY track 34 | ) 35 | SELECT p.id, 36 | t.track, 37 | SUM( ST_InterpolatePoint(b.geom, ST_EndPoint(dmp.geom)) - ST_InterpolatePoint(b.geom, ST_StartPoint(dmp.geom)) ) 38 | FROM poly AS p 39 | JOIN trajectory AS t 40 | ON ST_Intersects(p.geom, t.geom), 41 | LATERAL ST_Dump(ST_Intersection(p.geom, t.geom)) AS dmp 42 | GROUP BY 43 | p.id, t.track; 44 | ``` 45 | **Issues** 46 | * May not work if paths enter and exit polygon at same points? 47 | -------------------------------------------------------------------------------- /overlay/difference.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Difference, Symmetric Difference 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Polygon Difference 12 | 13 | ### Remove polygons from a surrounding box 14 | 15 | 16 | **Solution - Basic** 17 | 18 | Basic solution is too slow to use on 100K polygons 19 | 20 | ```sql 21 | SELECT ST_Difference( 22 | ST_MakeEnvelope(-124.7844079, 24.7433195, -66.9513812, 49.3457868, 4326), 23 | ST_UNION(union.geom)) as geom 24 | FROM polys 25 | WHERE ST_INTERSECTS(polys.geom, 26 | ST_MakeEnvelope(-124.7844079, 24.7433195, -66.9513812, 49.3457868, 4326)) 27 | ``` 28 | **Solution - reconstruct polygons as holes** 29 | 30 | **Solution - subdivide extent with Voronoi diagram** 31 | ```sql 32 | WITH 33 | pts AS (SELECT (ST_DumpPoints(geom)).geom FROM polys), 34 | vor AS (SELECT ((ST_Dump(ST_VoronoiPolygons(ST_Collect(geom)))).geom) geom FROM pts), 35 | clip AS (SELECT ST_Intersection(v.geom, b.geom) geom FROM vor v JOIN box b ON ST_Intersects(v.geom, b.geom)), 36 | diff AS (SELECT ST_Difference(c.geom, p.geom) geom FROM clip c 37 | JOIN polys p ON ST_Intersects(c.geom, p.geom) AND ST_Overlaps(c.geom, p.geom)) 38 | SELECT ST_Union(geom) geom FROM diff; 39 | ``` 40 | 41 | **Solution - subdivide extent as grid** 42 | 43 | **Issues** 44 | Basic approach is too slow to use (Note: user never actually completed processing, so might not have encountered geometry size issues, which could also occur) 45 | 46 | ### Remove polygon coverage from a single very large polygon 47 | . 48 | 49 | **Solution** 50 | * Use `ST_Subdivide` on large polygon 51 | * Compute difference between subdivided "squares" and `ST_Union` of overlapping coverage polygons 52 | * Union the remainders 53 | 54 | **Notes** 55 | * unioning the remainders may produce very narrow gores, if the difference operation used some robustness heuristics 56 | * the final unioned result is likely to be a very large polygon with many holes. This is inefficient to perform further processing on. It may be better to use the remainders directly, depending on the processing required. 57 | 58 | ```sql 59 | -- Turn NJ into a large number of small tractable areas 60 | CREATE SEQUENCE nj_square_id; 61 | CREATE TABLE nj_squares AS 62 | SELECT 63 | nextval('nj_square_id') AS nj_id, 64 | ST_SubDivide(geom) AS geom 65 | FROM nj; 66 | 67 | -- Index the squares for faster searching 68 | CREATE INDEX nj_squares_x ON nj_squares USING GIST (geom); 69 | 70 | -- Index parcels too in case you forgot 71 | CREATE INDEX parcels_x ON parcels USING GIST (geom); 72 | 73 | -- For each square, compute "bits that aren't parcels" 74 | CREATE TABLE nj_not_parcels AS 75 | WITH parcel_polys AS ( 76 | SELECT nj.nj_id, ST_Union(p.geom) AS geom 77 | FROM nj_squares nj 78 | JOIN parcels p 79 | ON ST_Intersects(p.geom, nj.geom) 80 | GROUP BY nj.nj_id 81 | ) 82 | SELECT nj_id, 83 | ST_Difference(nj.geom, pp.geom) AS geom 84 | FROM parcel_polys pp 85 | JOIN nj_squares 86 | USING (nj_id); 87 | ``` 88 | 89 | ### Remove Polygon table from another Polygon table 90 | 91 | 92 | 93 | 94 | 95 | 96 | #### Solution 97 | * For each target polygon, find union of all intersecting eraser polygons 98 | * Use `LEFT JOIN` to include targets with no intersections 99 | * Result is either difference of eraser from target, or original target (via `COALESCE`) 100 | 101 | ```sql 102 | WITH input(geom) AS (VALUES 103 | ( 'POLYGON ((10 50, 40 50, 40 10, 10 10, 10 50))'::geometry ), 104 | ( 'POLYGON ((70 50, 70 10, 40 10, 40 50, 70 50))'::geometry ), 105 | ( 'POLYGON ((90 50, 90 10, 70 10, 70 50, 90 50))'::geometry ), 106 | ( 'POLYGON ((90 90, 90 50, 70 50, 70 90, 90 90))'::geometry ) 107 | ), 108 | eraser(geom) AS (VALUES 109 | ( 'POLYGON ((30 60, 50 60, 50 40, 30 40, 30 60))'::geometry ), 110 | ( 'POLYGON ((30 30, 50 30, 50 10, 30 10, 30 30))'::geometry ), 111 | ( 'POLYGON ((60 40, 80 40, 80 20, 60 20, 60 40))'::geometry ) 112 | ) 113 | SELECT COALESCE( 114 | ST_Difference(i.geom, ie.geom), 115 | i.geom 116 | ) AS geom 117 | FROM input AS i 118 | LEFT JOIN LATERAL ( 119 | SELECT ST_Union(geom) AS geom 120 | FROM eraser AS e 121 | WHERE ST_Intersects(i.geom, e.geom) 122 | ) AS ie ON true ; 123 | ``` 124 | 125 | Similar: Find portions of countries not covered by administrative areas. 126 | 127 | 128 | 129 | ![](https://i.stack.imgur.com/0kFJj.png) 130 | 131 | ### Remove overlaps in a Polygon table by lower-priority polygons 132 | 133 | 134 | #### Solution 135 | 136 | Using `&&` greatly improves query performance. 137 | 138 | ```sql 139 | SELECT ST_Multi(COALESCE( 140 | ST_Difference(a.geom, blade.geom), 141 | a.geom 142 | )) AS geom 143 | FROM tbl AS a 144 | CROSS JOIN LATERAL ( 145 | SELECT ST_Union(geom) AS geom 146 | FROM tbl AS b 147 | WHERE a.geom && b.geom AND a.prio > b.prio 148 | ) AS blade; 149 | ``` 150 | 151 | ![](https://i.stack.imgur.com/W326R.png) 152 | 153 | 154 | ### Split Polygons by distance from a Polygon 155 | 156 | 157 | ### Cut Polygons into a Polygon table 158 | 159 | 160 | Use Case: cut a more detailed and attributed polygon coverage dataset (`detail`) into a less detailed polygon coverage (`base`). 161 | 162 | ```sql 163 | WITH detail_cutter AS ( 164 | SELECT ST_Union(d.geom) AS geom, b.gid 165 | FROM base b JOIN detail d ON ST_Intersects(b.geom, d.geom) 166 | GROUP BY b.gid 167 | ), 168 | base_rem AS ( 169 | SELECT ST_Difference(b.geom, d.geom) AS geom, b.gid 170 | FROM base b JOIN detail_cutter d ON b.gid = d.gid 171 | ) 172 | -- base remainders 173 | SELECT 'base' AS type, b.geom, b.gid 174 | FROM base_rem b 175 | UNION ALL 176 | -- cutter polygons 177 | SELECT 'detail' AS type, d.geom, d.gid 178 | FROM detail d 179 | UNION ALL 180 | -- uncut base polygons 181 | SELECT 'base' AS type, b.geom, b.gid 182 | FROM base b 183 | LEFT JOIN detail d ON ST_Intersects(b.geom,d.geom) 184 | WHERE d.gid is null; 185 | ``` 186 | 187 | #### Solution 188 | * For each base polygon, union all detail polygons which intersect it (the "cutters") 189 | * Difference the cutter union from the base polygon 190 | * UNION ALL: 191 | * The base polygon remainders 192 | * The cutter polygons 193 | * The uncut base polygons 194 | 195 | ### Remove MultiPolygons from LineStrings 196 | 197 | 198 | 199 | #### Solution ` 200 | ```sql 201 | SELECT COALESCE(ST_Difference(river.geom, lakes.geom), river.geom) As river_geom 202 | FROM river 203 | LEFT JOIN lakes ON ST_Intersects(river.geom, lakes.geom); 204 | ``` 205 | 206 | #### Solution 2 207 | 208 | 209 | 210 | 211 | #### Solution 212 | ```sql 213 | SELECT row_number() over() AS gid, 214 | ST_CollectionExtract(ST_Multi(ST_Difference(a.geom, b.geom)), 2)::geometry(MultiLineString, 27700) as geom 215 | FROM lines a 216 | JOIN LATERAL ( 217 | SELECT ST_UNION(polygons.geom) 218 | FROM polygons 219 | WHERE ST_Intersects(a.geom,polygons.geom) 220 | ) AS b; 221 | ``` 222 | 223 | ### Extract Block faces Lines from Parcel Polygons 224 | 225 | 226 | ![](https://i.stack.imgur.com/aEXYa.jpg) 227 | 228 | #### Solution 1 229 | Union all polygons to get block polygons, subtract from parcel boundaries 230 | 231 | ```sql 232 | SELECT block.id, ST_Intersection(block.geom, boundary.geom) geom 233 | FROM block 234 | JOIN ( 235 | SELECT ST_Boundary((ST_Dump(ST_Union(geom))).geom) geom 236 | FROM block) boundary 237 | ON ST_Intersects(block.geom, boundary.geom) 238 | ``` 239 | #### Solution 2 240 | For each parcel, union all adjacent parcels and subtract from parcel boundary. 241 | 242 | ```sql 243 | WITH parcels(id, geom) AS (VALUES 244 | ( 'a1', 'POLYGON ((10 10, 10 30, 30 30, 30 10, 10 10))'::geometry ), 245 | ( 'a2', 'POLYGON ((50 10, 30 10, 30 30, 50 30, 50 10))'::geometry ), 246 | ( 'a3', 'POLYGON ((10 50, 30 50, 30 30, 10 30, 10 50))'::geometry ), 247 | ( 'a4', 'POLYGON ((50 50, 50 30, 30 30, 30 50, 50 50))'::geometry ) 248 | ) 249 | SELECT p.id, 250 | ST_Difference( ST_Boundary(p.geom), pp.geom ) AS geom 251 | FROM parcels p 252 | JOIN LATERAL (SELECT ST_Collect(ST_Boundary(p2.geom)) AS geom 253 | FROM parcels p2 254 | WHERE p.id <> p2.id AND ST_Intersects(p.geom, p2.geom) ) AS pp ON true; 255 | ``` 256 | **Advantages:** 257 | 258 | * scales to an unlimited number of parcels 259 | * may provide better feedback if the parcels are not noded correctly (since more of each parcel's linework is kept) 260 | 261 | ## Polygon Symmetric Difference 262 | 263 | ### Construct symmetric difference of two tables 264 | https://gis.stackexchange.com/questions/302458/symmetrical-difference-between-two-layers 265 | 266 | 267 | -------------------------------------------------------------------------------- /overlay/index.md: -------------------------------------------------------------------------------- 1 | --- 2 | has_children: true 3 | --- 4 | 5 | # Overlay 6 | -------------------------------------------------------------------------------- /overlay/intersection.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Intersection, Clipping 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Polygon Intersection 12 | 13 | ### Aggregated Intersection 14 | 15 | 16 | 17 | 18 | 19 | #### Solutions 20 | * Define an aggregate function (given in #2) 21 | * Define a function to do the looping 22 | * Use a recursive CTE (see SQL in #2) 23 | 24 | ```sql 25 | CREATE AGGREGATE ST_IntersectionAgg ( 26 | basetype = geometry, 27 | stype = geometry, 28 | sfunc = ST_Intersection 29 | ); 30 | ``` 31 | **Example:** 32 | ```sql 33 | WITH data(geom) AS (VALUES 34 | ( ST_Buffer(ST_Point(0,0), 0.75) ), 35 | ( ST_Buffer(ST_Point(1,0), 0.75) ), 36 | ( ST_Buffer(ST_Point(0.5,1), 0.75) ) 37 | ) 38 | SELECT ST_IntersectionAgg(geom) FROM data; 39 | ``` 40 | 41 | #### Issues 42 | * How to find all groups of intersecting polygons. DBSCAN maybe? (This is suggested in an answer) 43 | 44 | 45 | ### Intersection returning only Polygons 46 | 47 | 48 | Possibly can use `ST_CollectionExtract`? 49 | 50 | **See also** 51 | * discusses a problem with QGIS visualization caused by the return of a `GEOMETRYCOLLECTION` from `ST_Intersection`. 52 | 53 | ### Intersection performance - Check containment first 54 | https://postgis.net/2014/03/14/tip_intersection_faster/ 55 | 56 | ### Intersection performance - Use Polygons instead of MultiPolygons 57 | 58 | 59 | ## Clipping 60 | 61 | ### Clip Districts to Coastline 62 | http://blog.cleverelephant.ca/2019/07/simple-sql-gis.html 63 | 64 | ### Clip Unioned Polygons to remove water bodies 65 | https://gis.stackexchange.com/questions/331887/unioning-a-set-of-intersections 66 | 67 | -------------------------------------------------------------------------------- /overlay/lines.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Lines 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Line Intersection 12 | ### Intersection of Lines which are not exactly coincident 13 | 14 | 15 | 16 | ## Line Merging 17 | ### Merge/Node Lines in a linear network 18 | 19 | 20 | **Solution** 21 | Use ST_Node, then ST_LineMerge 22 | 23 | ### Merge Lines and preserve direction 24 | 25 | 26 | SOLUTION 1 27 | Use a recursive CTE to group contiguous lines so they can be merged 28 | 29 | ```sql 30 | WITH RECURSIVE 31 | data AS (SELECT 32 | --'MULTILINESTRING((0 0, 1 1), (2 2, 1 1), (2 2, 3 3), (3 3, 4 4))'::geometry 33 | 'MULTILINESTRING( (0 0, 1 1), (1 1, 2 2), (3 3, 2 2), (4 4, 3 3), (4 4, 5 5), (5 5, 6 6) )'::geometry 34 | AS geom) 35 | ,lines AS (SELECT t.path[1] AS id, t.geom FROM data, LATERAL ST_Dump(data.geom) AS t) 36 | ,paths AS ( 37 | SELECT * FROM 38 | (SELECT l1.id, l1.geom, l1.id AS startid, l2.id AS previd 39 | FROM lines AS l1 LEFT JOIN lines AS l2 ON ST_EndPoint(l2.geom) = ST_StartPoint(l1.geom)) AS t 40 | WHERE previd IS NULL 41 | UNION ALL 42 | SELECT l1.id, l1.geom, startid, p.id AS previd 43 | FROM paths p 44 | INNER JOIN lines l1 ON ST_EndPoint(p.geom) = ST_StartPoint(l1.geom) 45 | ) 46 | SELECT ST_AsText( ST_LineMerge(ST_Collect(geom)) ) AS geom 47 | FROM paths 48 | GROUP BY startid; 49 | ``` 50 | 51 | SOLUTION 2 52 | ST_LIneMerge merges lines irrespective of direction. 53 | Perhaps a flag could be added to respect direction? 54 | 55 | See Also 56 | 57 | 58 | ### Merge lines to simplify a road network 59 | Merge lines with common attributes at degree-2 nodes 60 | 61 | 62 | 63 | 64 | ## Line Splitting 65 | 66 | ### Split Self-Overlapping Lines at Points not on the lines 67 | 68 | 69 | ### Split Lines by Polygons 70 | 71 | 72 | ### Split Lines by Polygons and order the sections 73 | 74 | 75 | ![](https://i.stack.imgur.com/ren10.png) 76 | 77 | **Solution** 78 | 79 | * Use `ST_Dump` to extract all sections if the intersection is a `MultiLineString` 80 | * Order the line sections by the location of their start point along the parent line 81 | 82 | ```sql 83 | WITH polys(id, geom) AS (VALUES 84 | (1,'POLYGON((2 2, 2 4, 4 4, 4 2, 2 2))'::geometry), 85 | (2,'POLYGON((4 2, 4 4, 5 4, 5 2, 4 2))'::geometry), 86 | (3,'POLYGON((5 2, 5 4, 5.5 4, 5.5 2, 5 2))'::geometry), 87 | (4,'POLYGON((5.5 2, 5.5 4, 7 4, 7 2, 5.5 2))'::geometry), 88 | 89 | (5,'POLYGON((3 9, 4 9, 4 6, 6 6, 6 9, 7 9, 7 5, 3 5, 3 9))'::geometry), 90 | (6,'POLYGON((1 9, 3 9, 3 5, 1 5, 1 9))'::geometry), 91 | (7,'POLYGON((4 9, 6 9, 6 6, 4 6, 4 9))'::geometry), 92 | (8,'POLYGON((7 9, 8 9, 8 5, 7 5, 7 9))'::geometry) 93 | ), 94 | lines(id, geom) AS (VALUES 95 | (1, 'LINESTRING(3 3, 6 3)'::geometry), 96 | (2, 'LINESTRING(2 7, 9 7)'::geometry) 97 | ), 98 | sections AS (SELECT p.id polyid, 99 | l.id lineid, 100 | l.geom as linegeom, 101 | (ST_Dump( ST_Intersection(p.geom, l.geom) )).geom section 102 | FROM polys p 103 | JOIN lines l 104 | ON ST_Intersects(p.geom, l.geom) 105 | ) 106 | SELECT lineid, polyid, 107 | row_number() OVER( PARTITION BY lineid 108 | ORDER BY ST_LineLocatePoint(linegeom, ST_StartPoint(section)) ) sectioNum, 109 | ST_Length(section) length, 110 | ST_AsText(section) 111 | FROM sections; 112 | ``` 113 | 114 | ## Overlay - Lines 115 | 116 | 117 | ### Count All Intersections Between 2 Linestrings 118 | 119 | 120 | ### Remove Line Overlaps Hierarchically 121 | 122 | -------------------------------------------------------------------------------- /overlay/noding.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Noding 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ### Node (Split) a table of lines by another table of lines 12 | https://lists.osgeo.org/pipermail/postgis-users/2019-September/043617.html 13 | 14 | ### Node a table of lines with itself 15 | https://gis.stackexchange.com/questions/368996/intersecting-line-at-junction-in-postgresql 16 | 17 | ### Node a table of Lines by a Set of Points 18 | https://gis.stackexchange.com/questions/332213/split-lines-with-points-postgis 19 | 20 | ### Compute points of intersection for a LineString 21 | https://gis.stackexchange.com/questions/16347/is-there-a-postgis-function-for-determining-whether-a-linestring-intersects-itse 22 | 23 | ### Compute location of noding failures 24 | https://gis.stackexchange.com/questions/345341/get-location-of-postgis-geos-topology-exception 25 | 26 | Using ST_Node on set of linestrings produces an error with no indication of where the problem occurs. Currently ST_Node uses IteratedNoder, which nodes up to 6 times, ahd fails if intersections are still found. 27 | Solution 28 | Would be possible to report the nodes found in the last pass, which wouild indicate where the problems occur. 29 | 30 | Would be better to eliminate noding errors via snap-rounding, or some other kind of snapping 31 | 32 | ### Clip Set of LineString by intersection points 33 | https://gis.stackexchange.com/questions/154833/cutting-linestrings-with-points 34 | 35 | Uses `ST_Split_Multi` from here: https://github.com/Remi-C/PPPP_utilities/blob/master/postgis/rc_split_multi.sql 36 | 37 | ### Construct locations where LineStrings self-intersect 38 | https://gis.stackexchange.com/questions/367120/getting-st-issimple-reason-and-detail-similar-to-st-isvaliddetail-in-postgis 39 | 40 | Solution 41 | SQL to compute LineString self-intersetions is provided 42 | 43 | 44 | -------------------------------------------------------------------------------- /overlay/overlay.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Dataset Overlay 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Dataset with Overlapping Polygons 12 | 13 | ### Create coverage from Nested Polygons 14 | 15 | 16 | ### Create Coverage from Overlapping Polygons 17 | 18 | 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | **Solution** 28 | One answer suggests the standard `Extract Lines > Node > Polygonize` approach (although does not include the PIP parentage step). But a comment says that this does not scale well (Pierre Racine…). 29 | 30 | See also PostGIS wiki: 31 | 32 | 33 | ### Count Overlap Depth in set of polygons 34 | 35 | 36 | 37 | ![](http://blog.cleverelephant.ca/images//2019/overlays8.png) 38 | 39 | Howver, this post indicates this approach might be slow for large datasets: 40 | 41 | 42 | #### Solution 43 | * Extract linework of polygons using `ST_Boundary` 44 | * Compute overlay of dataset using `ST_Union` 45 | * sometimes `ST_Node` is suggested, but this does not dissolve linework, which causes problems with polgonization 46 | * Polygonize linwork using `ST_Polygonize` 47 | * Generate an interior point for each resultant using `ST_PointOnSurface` 48 | * Count resultant overlap depth by joining back to original dataset with `ST_Contains` 49 | 50 | ### Identify Overlapping Polygon Resultant Parentage 51 | 52 | 53 | 54 | ### Return only polygons from Overlay 55 | 56 | 57 | 58 | 59 | #### Problem 60 | Reduce a dataset of highly overlapping polygons to a coverage (not clear if attribution is needed or not) 61 | 62 | #### Issues 63 | User implements a very complex overlay process, but can not get it to work, likely due to robustness problems 64 | 65 | #### Solution 66 | `ST_Boundary` -> `ST_Union` -> `ST_Polygonize` ?? 67 | 68 | ## Polygonal Coverages 69 | 70 | ### Overlay of two polygon layers - by Intersection 71 | 72 | Solution retains all areas from first layer, but not the second: 73 | 74 | 75 | This has what looks like a complete solution (although complex): 76 | 82 | 83 | ### Overlay of two polygon layers - by Node-Polygonize 84 | 85 | * Extract linework using `ST_Boundary` 86 | * Node/dissolve lines using `ST_Union` 87 | * Sometimes `ST_Node` is suggested, but it does not dissolve duplicate lines 88 | * Polygonize resultants using `ST_Polygonize` 89 | * Generate an interior point for each resultant using `ST_PointOnSurface` 90 | * Attach parent attribution by joining on interior points using `ST_Contains` 91 | 92 | #### Notes 93 | * All intermediate operations are dataset-wide, so materializing as intermediate tables will not improve performance. 94 | * But it might help with memory usage, and monitoring progress 95 | * The input tables should have spatial indexes, to improve performance of the final join step 96 | * Compard to the intersection approach, this approach: 97 | * reduces the chance of a topology error due to input precision or invalidity 98 | * is more likely to produce a non-overlapping coverage as a result 99 | * This approach generalizes easily to multiple tables, 100 | 101 | 102 | 103 | 104 | ```sql 105 | WITH poly_a(id, geom) AS (VALUES 106 | ( 'a1', 'POLYGON ((10 40, 30 40, 30 10, 10 10, 10 40))'::geometry ), 107 | ( 'a2', 'POLYGON ((70 10, 30 10, 30 90, 70 90, 70 10), (40 40, 60 40, 60 20, 40 20, 40 40), (40 80, 60 80, 60 60, 40 60, 40 80))'::geometry ), 108 | ( 'a3', 'POLYGON ((40 40, 60 40, 60 20, 40 20, 40 40))'::geometry ) 109 | ) 110 | ,poly_b(id, geom) AS (VALUES 111 | ( 'b1', 'POLYGON ((90 70, 90 50, 50 50, 50 70, 90 70))'::geometry ), 112 | ( 'b2', 'POLYGON ((90 30, 50 30, 50 50, 90 50, 90 30))'::geometry ), 113 | ( 'b2', 'POLYGON ((90 10, 70 10, 70 30, 90 30, 90 10))'::geometry ) 114 | ) 115 | ,lines AS ( 116 | SELECT ST_Boundary(geom) AS geom FROM poly_a 117 | UNION ALL 118 | SELECT ST_Boundary(geom) AS geom FROM poly_b 119 | ) 120 | ,noded_lines AS ( SELECT ST_Union(geom) AS geom FROM lines ) 121 | ,resultants AS ( 122 | SELECT geom, ST_PointOnSurface(geom) AS pip 123 | FROM St_Dump( 124 | ( SELECT ST_Polygonize(geom) AS geom FROM noded_lines )) 125 | ) 126 | SELECT a.id AS ida, b.id AS idb, r.geom 127 | FROM resultants r 128 | LEFT JOIN poly_a a ON ST_Contains(a.geom, r.pip) 129 | LEFT JOIN poly_b b ON ST_Contains(b.geom, r.pip) 130 | WHERE a.id IS NOT NULL OR b.id IS NOT NULL; 131 | ``` 132 | ![image](https://user-images.githubusercontent.com/3529053/121740578-1fb6df80-cab2-11eb-93a5-eb28966766cf.png) 133 | ![image](https://user-images.githubusercontent.com/3529053/121740709-5b51a980-cab2-11eb-8b78-d74e30aede65.png) 134 | 135 | 136 | ### Remove Polygons overlapped area on update to Polygon in other table 137 | 138 | 139 | ### Improve performance of a coverage overlay 140 | 141 | 142 | #### Problem 143 | Finding all intersections of a large set of parcel polygons against a set of jurisdiction polygons is slow 144 | 145 | #### Solution 146 | Reduce # calls to ST_Intersection by testing if parcel is wholly contained in polygon. 147 | ```sql 148 | INSERT INTO parcel_jurisdictions(parcel_gid,jurisdiction_gid,isect_geom) 149 | SELECT a.orig_gid AS parcel_gid, b.orig_gid AS jurisdiction_gid, 150 | CASE 151 | WHEN ST_Within(a.geom,b.geom) THEN a.geom 152 | ELSE ST_Multi(ST_Intersection(a.geom,b.geom)) 153 | END AS geom 154 | FROM valid_parcels a 155 | JOIN valid_jurisdictions b ON ST_Intersects(a.geom, b.geom); 156 | ``` 157 | References 158 | 159 | 160 | ### Sum rectangular grid values weighted by area of overlap with Polygons 161 | 162 | 163 | ![](https://i.stack.imgur.com/NQ8zu.jpg) 164 | 165 | ### Sum Percentage of Polygons intersected by other Polygons, by label 166 | 167 | Given two polygonal coverages A and B with labels, compute the percentage area of each polygon in A covered by each label in B. 168 | 169 | 170 | 171 | 172 | ![](https://i.stack.imgur.com/bQjSi.png) 173 | 174 | ```sql 175 | WITH poly_a(name, geom) AS (VALUES 176 | ( 'a1', 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'::geometry ), 177 | ( 'a2', 'POLYGON ((300 300, 300 200, 200 200, 200 300, 300 300))'::geometry ), 178 | ( 'a3', 'POLYGON ((400 400, 400 300, 300 300, 300 400, 400 400))'::geometry ) 179 | ), 180 | poly_b(name, geom) AS (VALUES 181 | ( 'b1', 'POLYGON ((120 280, 280 280, 280 120, 120 120, 120 280))'::geometry ), 182 | ( 'b2', 'POLYGON ((280 280, 280 320, 320 320, 320 280, 280 280))'::geometry ), 183 | ( 'b2', 'POLYGON ((390 390, 390 360, 360 360, 360 390, 390 390))'::geometry ) 184 | ) 185 | SELECT a.name, b.name, SUM( ST_Area(ST_Intersection(a.geom, b.geom))/ST_Area(a.geom) ) pct 186 | FROM poly_a a JOIN poly_b b ON ST_Intersects(a.geom, b.geom) 187 | GROUP BY a.name, b.name; 188 | ``` 189 | 190 | 191 | 192 | -------------------------------------------------------------------------------- /overlay/split.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Splitting 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ### Split Polygons by multiple LineStrings 12 | 13 | 14 | ![](https://i.stack.imgur.com/yP0rj.png) 15 | 16 | 17 | ### Split rectangles along North-South axis 18 | 19 | 20 | ### Split rotated rectangles into equal parts 21 | 22 | 23 | See also next problem 24 | 25 | ### Split Polygons into equal-area parts 26 | 27 | 28 | ![](http://blog.cleverelephant.ca/images/2018/poly-split-6.jpg) 29 | 30 | Does this really result in equal-area subdivision? The Voronoi-of-centroid step is distance-based, not area based…. So may not always work? Would be good to try this on a bunch of country outines 31 | 32 | ### Splitting by Line creates narrow gap in Polygonal coverage 33 | 34 | 35 | The cause is that vertex introduced by splitting is not present in adjacent polygon. 36 | 37 | * Perhaps differencing splitting line from surrounding intersecting polygon would introduce that vertex? 38 | * Or is it better to snap surrounding polygons to split vertices? Probably need a complex process to do this - not really something that can be done easily in DB? 39 | 40 | ### Splitting Polygon creates invalid coverage with holes 41 | 42 | 43 | #### Solution 44 | None so far. Need some way to create a clean coverage 45 | -------------------------------------------------------------------------------- /overlay/union.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Overlay 3 | --- 4 | 5 | # Union 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Polygon Union 12 | 13 | ### Union Polygons from two tables, grouped by name 14 | 15 | 16 | ![](https://i.stack.imgur.com/AUz4x.png) 17 | 18 | ```sql 19 | SELECT name, ST_Multi(ST_Union(geom)) AS geom 20 | FROM ( 21 | SELECT name, geom FROM table1 22 | UNION ALL 23 | SELECT name, geom FROM table2 ) q 24 | GROUP BY name; 25 | ``` 26 | 27 | ### Boundary of Coverage of Polygons 28 | 29 | 30 | **Solution** 31 | Union, then extract boundary 32 | 33 | ### Union of set of geometry specified by IDs 34 | ```sql 35 | SELECT ST_Union(geom)) 36 | FROM ( SELECT geom FROM table WHERE id IN ( … ) ) as t; 37 | ``` 38 | 39 | ### Union of Point cells grouped by ID 40 | 41 | 42 | ![](https://i.stack.imgur.com/UioAZ.png) 43 | 44 | ```sql 45 | DO 46 | $$ 47 | DECLARE 48 | _cluster_id UUID; 49 | _cluster_geometry GEOMETRY; 50 | BEGIN 51 | FOR _cluster_id IN SELECT id FROM ds_forecast_objects.clusters 52 | LOOP 53 | SELECT st_union(st_expand(gn.geom, 0.0041, 0.0023)) INTO _cluster_geometry 54 | FROM grid_nodes as gn 55 | JOIN grid_node_clusters as gnc 56 | ON gn.id = gnc.grid_node_id AND gnc.cluster_id = _cluster_id; 57 | 58 | INSERT INTO clusters_geometry(cluster_id, geom) 59 | VALUES (_cluster_id, _cluster_geometry); 60 | END LOOP; 61 | END 62 | $$ 63 | ``` 64 | 65 | ### Union of polygons with equal or lower value 66 | 67 | 68 | **Solution** 69 | Use of window functions with `PARTITION BY` and `ORDER BY`. 70 | 71 | Not sure what happens if there are two polygons with same value though? 72 | 73 | 74 | ### Union Non-clean Polygons 75 | 76 | 77 | ![](https://i.stack.imgur.com/5P53M.png) 78 | 79 | **Solution** 80 | Snap Polygons to grid to help clean invalid polygons 81 | ```sql 82 | SELECT ST_Union(ST_SnapToGrid(the_geom,0.0001)) 83 | FROM parishes 84 | GROUP BY county_name; 85 | ``` 86 | 87 | ## Union Groups of Edge-Adjacent Polygons 88 | 89 | ### Union Edge-Adjacent Polygons 90 | 91 | 92 | ![](https://i.stack.imgur.com/bTRzU.png) 93 | 94 | **Solution** 95 | 96 | Group the polygons via an intersects relationship and union the partitions. 97 | This can be done in-memory using `ST_ClusterIntersecting`, or non-memory bound by using `ST_ClusterDBSCAN`. 98 | 99 | ```sql 100 | SELECT ST_UnaryUnion( UNNEST( ST_ClusterIntersecting(geom) ) ) FROM polys; 101 | ``` 102 | 103 | ### Union Edge-Adjacent Polygons, keeping attributes 104 | Only union polygons which share an edge (not just touch). 105 | 106 | * 107 | * 108 | 109 | **Solution** 110 | No good solution so far. 111 | What is needed is a function similar to `ST_ClusterIntersecting` but which does not group polygons which touch only at points. 112 | 113 | ### Union Groups of Adjacent Polygon, keeping attribution for singletons 114 | 115 | 116 | **Solution** 117 | Use `ST_ClusterDBSCAN` with a zero (or very small) distance 118 | 119 | ## Union with Gap Removal 120 | 121 | ### Polygon Coverage Union with slivers removed 122 | 123 | 124 | Solution - NOT SURE 125 | 126 | ### Polygon Coverage Union with gaps removed 127 | 128 | 129 | 130 | 131 | Both of these have answers recommending using a small buffer outwards and then the inverse on the result. 132 | 133 | ### Union groups of almost-adjacent polygons 134 | 135 | 136 | ![](https://i.stack.imgur.com/1RCSR.png) 137 | 138 | **Solution** 139 | (lossy) 140 | ```sql 141 | SELECT (ST_DUMP(ST_UNION(ST_SNAPTOGRID(the_geom,0.0001)))).geom, color 142 | FROM my_poly 143 | GROUP BY color 144 | ``` 145 | 146 | ### Enlarge Polygons to Fill Boundary 147 | 148 | 149 | ### Create polygons that fill gaps 150 | 151 | 152 | ![](https://i.stack.imgur.com/PjcTl.png) 153 | 154 | ```sql 155 | WITH polygons(geom) AS 156 | (VALUES (ST_Buffer(ST_Point(0, 0), 1.1,3)), 157 | (ST_Buffer(ST_Point(0, 2), 1.1,3)), 158 | (ST_Buffer(ST_Point(2, 2), 1.1,3)), 159 | (ST_Buffer(ST_Point(2, 0), 1.1,3)), 160 | (ST_Buffer(ST_Point(4, 1), 1.3,3)) 161 | ), 162 | bigpoly AS 163 | (SELECT ST_UNION(geom)geom 164 | FROM polygons) 165 | SELECT ST_BuildArea(ST_InteriorRingN(geom,i)) 166 | FROM bigpoly 167 | CROSS JOIN generate_series(1,(SELECT ST_NumInteriorRings(geom) FROM bigpoly)) as i; 168 | ``` 169 | 170 | 171 | ## Union of Large datasets 172 | 173 | ### Union of Massive Number of Point Buffers using GeoHash spatial partitioning 174 | 175 | 176 | Union a massive number of buffers around points which have an uneven distribution (points are demographic data in the UK). 177 | Using plain `ST_Union` runs out of memory. 178 | 179 | ![](https://i.stack.imgur.com/BFQ5w.jpg) 180 | 181 | **Solution** 182 | 183 | Implement a “SQL-level” **cascaded union**: 184 | * spatially sort data based on `ST_GeoHash` 185 | * union smaller partitions of the data (e.g. partition size = 100K) 186 | * union the partitions together 187 | 188 | ```sql 189 | CREATE SEQUENCE bseq; 190 | 191 | WITH ordered AS ( 192 | SELECT ST_Buffer(geom, 10) AS geom 193 | FROM points 194 | ORDER BY ST_GeoHash(geom) 195 | ), 196 | grouped AS ( 197 | SELECT nextval('bseq') / 100000 AS id, ST_Union(geom) AS geom 198 | FROM ordered 199 | GROUP BY id 200 | ) 201 | groupedfinal AS ( 202 | SELECT ST_Union(geom) AS geom 203 | FROM grouped 204 | ) 205 | SELECT * FROM groupedfinal; 206 | ``` 207 | 208 | ### Union by Spatial Partition via Intersection 209 | 210 | 211 | If a dataset is fairly sparse, it may provide a performance and memory advantage to union 212 | by groups of geometries partitioned by a "touches" relation. 213 | This can be done by using grouping the geometries via `ST_ClusterDBSCAN` with a zero or small distance, 214 | and then unioning the groups. 215 | 216 | If needed the result could then be unioned once again to create a single result geometry. 217 | In theory the partitions should be disjoint, so potentially just collecting them should be faster 218 | and produce a valid MultiPolygon. 219 | 220 | ![](https://i.stack.imgur.com/yN31B.png) 221 | 222 | **Solution** 223 | ```sql 224 | SELECT ST_Union(geom) AS geom 225 | FROM ( SELECT geom, 226 | ST_ClusterDBSCAN(geom, 0, 1) OVER () AS _id 227 | FROM input 228 | GROUP BY _id); 229 | ``` 230 | 231 | ### Union Large Datasets (Questions only) 232 | 233 | These questions are looking for union of large sets of polygons. 234 | 235 | * 236 | * 237 | * 238 | 239 | 240 | -------------------------------------------------------------------------------- /pgp-OLD-lines.md: -------------------------------------------------------------------------------- 1 | --- 2 | nav_exclude: true 3 | --- 4 | 5 | # Lines and Networks 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Linear Referencing/Line Handling 12 | 13 | ### Select every Nth point from a LineString 14 | https://stackoverflow.com/questions/60319473/postgis-how-do-i-select-every-second-point-from-linestring 15 | 16 | ### Extrapolate Lines 17 | https://gis.stackexchange.com/questions/33055/extrapolating-a-line-in-postgis 18 | 19 | ST_LineInterpolatePoint should be enhanced to allow fractions outside [0,1]. 20 | 21 | ### Extend a LineString to the boundary of a polygon 22 | https://gis.stackexchange.com/questions/345463/how-can-i-extend-a-linestring-to-the-edge-of-an-enclosing-polygon-in-postgis 23 | 24 | Ideas 25 | A function ST_LineExtract(line, index1, index2) to extract a portion of a LineString between two indices 26 | 27 | 28 | 29 | 30 | 31 | ### Extract Line Segments 32 | 33 | 34 | #### PostGIS Idea 35 | Create an `ST_DumpSegments` to do this. 36 | 37 | 38 | 39 | 40 | 41 | 42 | ## Networks 43 | ### Find Shortest Path through linear network 44 | Input Parameters: linear network MultiLineString, start point, end point 45 | 46 | Start and End point could be snapped to nearest endpoints if not already in network 47 | Maybe also function to snap a network? 48 | 49 | “Longest Shortest Path” - perhaps: construct Convex Hull, take longest diameter, find shortest path between those points 50 | 51 | https://gis.stackexchange.com/questions/295199/how-do-i-select-the-longest-connected-lines-from-postgis-st-approximatemedialaxi 52 | 53 | ## Routing / Pathfinding 54 | 55 | ### Seaway Distances & Routes 56 | https://www.ausvet.com.au/seaway-distances-with-postgresql/ 57 | ![](https://www.ausvet.com.au/wp-content/uploads/Blog_images/seaway_1.png) 58 | 59 | ## Temporal Trajectories 60 | 61 | ### Find Coincident Paths 62 | https://www.cybertec-postgresql.com/en/intersecting-gps-tracks-to-identify-infected-individuals/ 63 | 64 | ### Remove Stationary Points 65 | https://gis.stackexchange.com/questions/290243/remove-points-where-user-was-stationary 66 | 67 | -------------------------------------------------------------------------------- /pgp-OLD-overlay.md: -------------------------------------------------------------------------------- 1 | --- 2 | nav_exclude: true 3 | --- 4 | 5 | # OLD Overlay 6 | {: .no_toc } 7 | 8 | Overlay processes create geometry from existing ones with output vertices being either from the input 9 | or from intersection points between input line segments. 10 | Often the output geometry is associated with attribution from the inputs which create it. 11 | 12 | Overlay and related processing involved using the overlay operations of `ST_Intersection`, `ST_Union`, `ST_Difference` and `ST_SymDifference`, 13 | as well as `ST_Split` and `ST_Node`. 14 | 15 | 1. TOC 16 | {:toc} 17 | 18 | 19 | ## Noding 20 | 21 | ### Node (Split) a table of lines by another table of lines 22 | https://lists.osgeo.org/pipermail/postgis-users/2019-September/043617.html 23 | 24 | ### Node a table of lines with itself 25 | https://gis.stackexchange.com/questions/368996/intersecting-line-at-junction-in-postgresql 26 | 27 | ### Node a table of Lines by a Set of Points 28 | https://gis.stackexchange.com/questions/332213/split-lines-with-points-postgis 29 | 30 | ### Compute points of intersection for a LineString 31 | https://gis.stackexchange.com/questions/16347/is-there-a-postgis-function-for-determining-whether-a-linestring-intersects-itse 32 | 33 | ### Compute location of noding failures 34 | https://gis.stackexchange.com/questions/345341/get-location-of-postgis-geos-topology-exception 35 | 36 | Using ST_Node on set of linestrings produces an error with no indication of where the problem occurs. Currently ST_Node uses IteratedNoder, which nodes up to 6 times, ahd fails if intersections are still found. 37 | Solution 38 | Would be possible to report the nodes found in the last pass, which wouild indicate where the problems occur. 39 | 40 | Would be better to eliminate noding errors via snap-rounding, or some other kind of snapping 41 | 42 | ### Clip Set of LineString by intersection points 43 | https://gis.stackexchange.com/questions/154833/cutting-linestrings-with-points 44 | 45 | Uses `ST_Split_Multi` from here: https://github.com/Remi-C/PPPP_utilities/blob/master/postgis/rc_split_multi.sql 46 | 47 | ### Construct locations where LineStrings self-intersect 48 | https://gis.stackexchange.com/questions/367120/getting-st-issimple-reason-and-detail-similar-to-st-isvaliddetail-in-postgis 49 | 50 | Solution 51 | SQL to compute LineString self-intersetions is provided 52 | 53 | 54 | 55 | ## Line Intersection 56 | ### Intersection of Lines which are not exactly coincident 57 | https://stackoverflow.com/questions/60298412/wrong-result-using-st-intersection-with-postgis/60306404#60306404 58 | 59 | 60 | ## Line Merging 61 | ### Merge/Node Lines in a linear network 62 | https://gis.stackexchange.com/questions/238329/how-to-break-multilinestring-into-constituent-linestrings-in-postgis 63 | Solution 64 | Use ST_Node, then ST_LineMerge 65 | 66 | ### Merge Lines and preserve direction 67 | https://gis.stackexchange.com/questions/353565/how-to-join-linestrings-without-reversing-directions-in-postgis 68 | 69 | SOLUTION 1 70 | Use a recursive CTE to group contiguous lines so they can be merged 71 | 72 | ```sql 73 | WITH RECURSIVE 74 | data AS (SELECT 75 | --'MULTILINESTRING((0 0, 1 1), (2 2, 1 1), (2 2, 3 3), (3 3, 4 4))'::geometry 76 | 'MULTILINESTRING( (0 0, 1 1), (1 1, 2 2), (3 3, 2 2), (4 4, 3 3), (4 4, 5 5), (5 5, 6 6) )'::geometry 77 | AS geom) 78 | ,lines AS (SELECT t.path[1] AS id, t.geom FROM data, LATERAL ST_Dump(data.geom) AS t) 79 | ,paths AS ( 80 | SELECT * FROM 81 | (SELECT l1.id, l1.geom, l1.id AS startid, l2.id AS previd 82 | FROM lines AS l1 LEFT JOIN lines AS l2 ON ST_EndPoint(l2.geom) = ST_StartPoint(l1.geom)) AS t 83 | WHERE previd IS NULL 84 | UNION ALL 85 | SELECT l1.id, l1.geom, startid, p.id AS previd 86 | FROM paths p 87 | INNER JOIN lines l1 ON ST_EndPoint(p.geom) = ST_StartPoint(l1.geom) 88 | ) 89 | SELECT ST_AsText( ST_LineMerge(ST_Collect(geom)) ) AS geom 90 | FROM paths 91 | GROUP BY startid; 92 | ``` 93 | 94 | SOLUTION 2 95 | ST_LIneMerge merges lines irrespective of direction. 96 | Perhaps a flag could be added to respect direction? 97 | 98 | See Also 99 | https://gis.stackexchange.com/questions/74119/a-linestring-merger-algorithm 100 | 101 | ### Merge lines to simplify a road network 102 | Merge lines with common attributes at degree-2 nodes 103 | 104 | https://gis.stackexchange.com/questions/326433/st-linemerge-to-simplify-road-network?rq=1 105 | 106 | 107 | ## Line Splitting 108 | ### Split Self-Overlapping Lines at Points not on the lines 109 | https://gis.stackexchange.com/questions/347790/splitting-self-overlapping-lines-with-points-using-postgis 110 | 111 | ### Split Lines by Polygons 112 | https://gis.stackexchange.com/questions/215886/split-lines-by-polygons 113 | 114 | ## Overlay - Lines 115 | https://gis.stackexchange.com/questions/186242/how-to-get-smallest-line-segments-from-intersection-difference-of-multiple-ove 116 | ### Count All Intersections Between 2 Linestrings 117 | https://gis.stackexchange.com/questions/347790/splitting-self-overlapping-lines-with-points-using-postgis 118 | 119 | ### Remove Line Overlaps Hierarchically 120 | https://gis.stackexchange.com/questions/372572/how-to-remove-line-overlap-hierachically-in-postgis-with-st-difference 121 | 122 | ## Polygonization 123 | ### Polygonize OSM streets 124 | https://gis.stackexchange.com/questions/331529/split-streets-to-create-polygons 125 | 126 | ### Polygonize a set of lines 127 | https://gis.stackexchange.com/questions/231237/making-linestrings-with-adjacent-lines-in-postgis?rq=1 128 | 129 | ### Polygonize a set of isolines with bounding box 130 | https://gis.stackexchange.com/questions/127727/how-to-transform-isolines-to-isopolygons-with-postgis 131 | 132 | ### Find area enclosed by a set of lines 133 | https://gis.stackexchange.com/questions/373933/polygon-covered-by-the-intersection-of-multiple-linestrings-postgis/373983#373983 134 | 135 | 136 | 137 | ## Clipping 138 | 139 | ### Clip Districts to Coastline 140 | http://blog.cleverelephant.ca/2019/07/simple-sql-gis.html 141 | 142 | ### Clip Unioned Polygons to remove water bodies 143 | https://gis.stackexchange.com/questions/331887/unioning-a-set-of-intersections 144 | 145 | 146 | ## Polygon Intersection 147 | 148 | ### Aggregated Intersection 149 | 150 | 151 | 152 | 153 | 154 | #### Solutions 155 | * Define an aggregate function (given in #2) 156 | * Define a function to do the looping 157 | * Use a recursive CTE (see SQL in #2) 158 | 159 | #### Issues 160 | * How to find all groups of intersecting polygons. DBSCAN maybe? (This is suggested in an answer) 161 | * Intersection performance - Use Polygons instead of MultiPolygons 162 | * https://gis.stackexchange.com/questions/101425/using-multipolygon-or-polygon-features-for-large-intersect-operations 163 | 164 | ### Intersection performance - Check containment first 165 | https://postgis.net/2014/03/14/tip_intersection_faster/ 166 | 167 | 168 | 169 | ## Polygon Difference 170 | 171 | ### Subtract large set of polygons from a surrounding box 172 | https://gis.stackexchange.com/questions/330051/obtaining-the-geospatial-complement-of-a-set-of-polygons-to-a-bounding-box-in-po/333562#333562 173 | 174 | #### Issues 175 | conventional approach is too slow to use (Note: user never actually completed processing, so might not have encountered geometry size issues, which could also occur) 176 | 177 | ### Subtract MultiPolygons from LineStrings 178 | https://gis.stackexchange.com/questions/239696/subtract-multipolygon-table-from-linestring-table 179 | 180 | https://gis.stackexchange.com/questions/11592/difference-between-two-layers-in-postgis 181 | #### Solution 182 | ```sql 183 | SELECT COALESCE(ST_Difference(river.geom, lakes.geom), river.geom) As river_geom 184 | FROM river 185 | LEFT JOIN lakes ON ST_Intersects(river.geom, lakes.geom); 186 | ``` 187 | 188 | https://gis.stackexchange.com/questions/193217/st-difference-on-linestrings-and-polygons-slow-and-fails 189 | 190 | 191 | 192 | #### Solution 193 | ```sql 194 | SELECT row_number() over() AS gid, 195 | ST_CollectionExtract(ST_Multi(ST_Difference(a.geom, b.geom)), 2)::geometry(MultiLineString, 27700) as geom 196 | FROM lines a 197 | JOIN LATERAL ( 198 | SELECT ST_UNION(polygons.geom) 199 | FROM polygons 200 | WHERE ST_Intersects(a.geom,polygons.geom) 201 | ) AS b; 202 | ``` 203 | 204 | ### Split Polygons by distance from a Polygon 205 | https://gis.stackexchange.com/questions/78073/separate-a-polygon-in-different-polygons-depending-of-the-distance-to-another-po 206 | 207 | ### Cut Polygons into a Polygonal coverage 208 | https://gis.stackexchange.com/questions/71461/using-st-difference-and-preserving-attributes-in-postgis 209 | 210 | #### Solution 211 | For each base polygon, union all detailed polygons which intersect it 212 | Difference the detailed union from the each base polygon 213 | UNION ALL: 214 | The differenced base polygons 215 | The detailed polygons 216 | All remaining base polygons which were not changed 217 | 218 | ### Subtract Areas from a set of Polygons 219 | https://gis.stackexchange.com/questions/250674/postgis-st-difference-similar-to-arcgis-erase 220 | 221 | https://gis.stackexchange.com/questions/187406/how-to-use-st-difference-and-st-intersection-in-case-of-multipolygons-postgis 222 | 223 | https://gis.stackexchange.com/questions/90174/postgis-when-i-add-a-polygon-delete-overlapping-areas-in-other-layers 224 | 225 | https://gis.stackexchange.com/questions/155597/using-st-difference-to-remove-overlapping-features 226 | 227 | ```sql 228 | SELECT id, COALESCE(ST_Difference(geom, (SELECT ST_Union(b.geom) 229 | FROM parcels b 230 | WHERE ST_Intersects(a.geom, b.geom) 231 | AND a.id != b.id)), 232 | a.geom) 233 | FROM parcels a; 234 | ``` 235 | 236 | ### Find Part of Polygons not fully contained by union of other Polygons 237 | Find what countries are not fully covered by administrative boundaries and the geometry of part of country geometry 238 | where it is not covered by the administrative boundaries. 239 | 240 | https://gis.stackexchange.com/questions/313039/find-what-polygons-are-not-fully-covered-by-union-of-polygons-from-another-layer 241 | 242 | ![](https://i.stack.imgur.com/0kFJj.png) 243 | 244 | ### Remove overlaps by lower-priority polygons 245 | https://gis.stackexchange.com/questions/379300/how-to-remove-overlaps-and-keep-highest-priority-polygon 246 | 247 | #### Solution 248 | 249 | ```sql 250 | SELECT ST_Multi(COALESCE( 251 | ST_Difference(a.geom, blade.geom), 252 | a.geom 253 | )) AS geom 254 | FROM table1 AS a 255 | CROSS JOIN LATERAL ( 256 | SELECT ST_Union(geom) AS geom 257 | FROM table1 AS b 258 | WHERE a.prio > b.prio 259 | ) AS blade; 260 | ``` 261 | 262 | ![](https://i.stack.imgur.com/W326R.png) 263 | 264 | 265 | 266 | ## Polygon Symmetric Difference 267 | 268 | ### Construct symmetric difference of two tables 269 | https://gis.stackexchange.com/questions/302458/symmetrical-difference-between-two-layers 270 | 271 | 272 | 273 | 274 | ## Polygon Union 275 | 276 | ### Union Polygons from two tables, grouped by name 277 | https://gis.stackexchange.com/questions/378699/merging-two-multipolygon-tables-into-one-and-afterwards-dissolve-boundaries 278 | ```sql 279 | SELECT name, ST_Multi(ST_Union(geom)) AS geom 280 | FROM ( 281 | SELECT name, geom FROM table1 282 | UNION ALL 283 | SELECT name, geom FROM table2 ) q 284 | GROUP BY name; 285 | ``` 286 | 287 | ### Union of Massive Number of Point Buffers 288 | https://gis.stackexchange.com/questions/31880/memory-issue-when-trying-to-buffer-union-large-dataset-using-postgis?noredirect=1&lq=1 289 | 290 | Union a massive number of buffers around points which have an uneven distribution (points are demographic data in the UK). 291 | Using straight ST_Union runs out of memory 292 | Solution 293 | Implement a “SQL-level” cascaded union as follows: 294 | Spatially sort data based on ST_GeoHash 295 | union smaller partitions of the data (partition size = 100K) 296 | union the partitions together 297 | 298 | ### Polygon Coverage Union with slivers removed 299 | https://gis.stackexchange.com/questions/71809/is-there-a-dissolve-st-union-function-that-will-close-gaps-between-features?rq=1 300 | 301 | Solution - NOT SURE 302 | 303 | ### Polygon Coverage Union with gaps removed 304 | https://gis.stackexchange.com/questions/356480/is-it-possible-create-a-polygon-from-more-polygons-that-are-not-overlapped-but-c 305 | 306 | https://gis.stackexchange.com/questions/316000/using-st-union-to-combine-several-polygons-to-one-multipolygon-using-postgis/31612 307 | 308 | Both of these have answers recommending using a small buffer outwards and then the inverse on the result. 309 | 310 | ### Union Intersecting Polygons 311 | https://gis.stackexchange.com/questions/187728/alternative-to-st-union-st-memunion-for-merging-overlapping-polygons-using-postg?rq=1 312 | 313 | ### Union groups of polygons 314 | https://gis.stackexchange.com/questions/185393/what-is-the-best-way-to-merge-lots-of-small-adjacents-polygons-postgis?noredirect=1&lq=1 315 | 316 | ### Union Edge-Adjacent Polygons 317 | Only union polygons which share an edge (not just touch) 318 | https://gis.stackexchange.com/questions/1387/is-there-a-dissolve-function-in-postgis-other-than-st-union?rq=1 319 | https://gis.stackexchange.com/questions/24634/merging-polygons-that-intersect-by-more-than-a-specified-amount?rq=1 320 | https://gis.stackexchange.com/questions/127019/merge-any-and-all-adjacent-polygons?noredirect=1&lq=1 321 | Problem 322 | Union only polygons which intersect, keep non-intersecting ones unchanged. Goal is to keep attributes on non-intersecting polygons, and improve performance by unioning only groups of intersecting polygons 323 | Solution 324 | Should be able to find equivalence classes of intersecting polygons and union each separately? 325 | See Also 326 | 327 | ### Grouping touching Polygons 328 | Can use ST_DBSCAN with very small distance to group touching polygons 329 | 330 | ### Enlarge Polygons to Fill Boundary 331 | https://gis.stackexchange.com/questions/91889/adjusting-polygons-to-boundary-and-filling-holes?rq=1 332 | 333 | ### Boundary of Coverage of Polygons 334 | https://gis.stackexchange.com/questions/324736/extracting-single-boundary-from-multipolygon-in-postgis 335 | 336 | Solution 337 | The obvious: Union, then extract boundary 338 | 339 | ### Union of cells grouped by ID 340 | https://gis.stackexchange.com/questions/288880/finding-geometry-of-cluster-from-points-collection-using-postgis 341 | 342 | ### Union of set of geometry specified by IDs 343 | SELECT ST_Union(geo)) FROM ( SELECT geom FROM table WHERE id IN ( … ) ) as foo; 344 | 345 | ### Union of polygons with equal or lower value 346 | https://gis.stackexchange.com/questions/161849/postgis-sql-request-with-aggregating-st-union?rq=1 347 | Solution 348 | Nice use of window functions with PARTITION BY and ORDER BY. 349 | Not sure what happens if there are two polygons with same value though. Worth finding out 350 | 351 | ### Union Groups of Adjacent Polygon, keeping attribution for singletons 352 | https://gis.stackexchange.com/questions/366374/how-to-use-dissolve-a-subset-of-a-postgis-table-based-on-a-value-in-a-column 353 | 354 | Solution 355 | Use ST_ClusterDBSCAN 356 | 357 | ### Union Non-clean Polygons 358 | https://gis.stackexchange.com/questions/31895/joining-lots-of-small-polygons-to-form-larger-polygon-using-postgis 359 | 360 | ![](https://i.stack.imgur.com/5P53M.png) 361 | 362 | #### Solution - Snap Polygons to grid to help clean invalid polygons 363 | ```sql 364 | SELECT ST_Union(ST_SnapToGrid(the_geom,0.0001)) 365 | FROM parishes 366 | GROUP BY county_name; 367 | ``` 368 | ### Create polygons that fill gaps 369 | https://gis.stackexchange.com/questions/60655/creating-polygons-from-gaps-in-postgis 370 | 371 | ![](https://i.stack.imgur.com/PjcTl.png) 372 | 373 | ```sql 374 | WITH polygons(geom) AS 375 | (VALUES (ST_Buffer(ST_Point(0, 0), 1.1,3)), 376 | (ST_Buffer(ST_Point(0, 2), 1.1,3)), 377 | (ST_Buffer(ST_Point(2, 2), 1.1,3)), 378 | (ST_Buffer(ST_Point(2, 0), 1.1,3)), 379 | (ST_Buffer(ST_Point(4, 1), 1.3,3)) 380 | ), 381 | bigpoly AS 382 | (SELECT ST_UNION(geom)geom 383 | FROM polygons) 384 | SELECT ST_BuildArea(ST_InteriorRingN(geom,i)) 385 | FROM bigpoly 386 | CROSS JOIN generate_series(1,(SELECT ST_NumInteriorRings(geom) FROM bigpoly)) as i; 387 | ``` 388 | 389 | ## Polygon Splitting 390 | 391 | https://gis.stackexchange.com/questions/299849/split-polygon-into-separate-polygons-using-a-table-of-individual-lines 392 | 393 | ### Split rectangles along North-South axis 394 | https://gis.stackexchange.com/questions/239801/how-can-i-split-a-polygon-into-two-equal-parts-along-a-n-s-axis?rq=1 395 | 396 | ### Split rotated rectangles into equal parts 397 | https://gis.stackexchange.com/questions/286184/splitting-polygon-in-equal-parts-based-on-polygon-area 398 | 399 | See also next problem 400 | 401 | ### Split Polygons into equal-area parts 402 | http://blog.cleverelephant.ca/2018/06/polygon-splitting.html 403 | 404 | Does this really result in equal-area subdivision? The Voronoi-of-centroid step is distance-based, not area based…. So may not always work? Would be good to try this on a bunch of country outines 405 | 406 | ### Splitting by Line creates narrow gap in Polygonal coverage 407 | https://gis.stackexchange.com/questions/378705/postgis-splitting-polygon-with-line-returns-different-size-polygons-that-creat 408 | 409 | Cause is that vertex introduced by splitting is not present in adjacent polygon. 410 | 411 | > Perhaps differencing splitting line from surrounding intersecting polygon would introduce that vertex? 412 | > Or is it better to snap surrounding polygons to split vertices? Probably need a complex process to do this - not really something that can be done easily in DB? 413 | 414 | ### Splitting Polygon creates invalid coverage with holes 415 | https://gis.stackexchange.com/questions/344716/holes-after-st-split-with-postgis 416 | 417 | #### Solution 418 | None so far. Need some way to create a clean coverage 419 | 420 | 421 | ## Overlay Polygons 422 | 423 | https://gis.stackexchange.com/questions/109692/how-to-replicate-arcgis-intersect-in-postgis 424 | 425 | http://blog.cleverelephant.ca/2019/07/postgis-overlays.html 426 | 427 | ### Flatten / Create coverage from Nested Polygons 428 | https://gis.stackexchange.com/questions/266005/postgis-separate-nested-polygons 429 | 430 | ### Create Coverage from overlapping Polygons 431 | https://gis.stackexchange.com/questions/83/separate-polygons-based-on-intersection-using-postgis 432 | https://gis.stackexchange.com/questions/112498/postgis-overlay-style-union-not-dissolve-style 433 | Solution 434 | One answer suggests the standard Extract Lines > Node > Polygonize approach (although does not include the PIP parentage step). But a comment says that this does not scale well (Pierre Racine…). 435 | Also links to PostGIS wiki: https://trac.osgeo.org/postgis/wiki/UsersWikiExamplesOverlayTables 436 | 437 | ### Improve performance of a coverage overlay 438 | https://gis.stackexchange.com/questions/31310/acquiring-arcgis-like-speed-in-postgis/31562 439 | Problem 440 | Finding all intersections of a large set of parcel polygons against a set of jurisdiction polygons is slow 441 | Solution 442 | Reduce # calls to ST_Intersection by testing if parcel is wholly contained in polygon. 443 | ```sql 444 | INSERT INTO parcel_jurisdictions(parcel_gid,jurisdiction_gid,isect_geom) 445 | SELECT a.orig_gid AS parcel_gid, b.orig_gid AS jurisdiction_gid, 446 | CASE WHEN ST_Within(a.geom,b.geom) THEN a.geom ELSE ST_Multi(ST_Intersection(a.geom,b.geom)) END AS geom 447 | FROM valid_parcels a 448 | JOIN valid_jurisdictions b ON ST_Intersects(a.geom, b.geom); 449 | ``` 450 | References 451 | https://postgis.net/2014/03/14/tip_intersection_faster/ 452 | 453 | 454 | ### Find non-covered polygons 455 | https://gis.stackexchange.com/questions/333302/selecting-non-overlapping-polygons-from-a-one-layer-in-postgis/334217 456 | ```sql 457 | WITH 458 | data AS ( 459 | SELECT * FROM (VALUES 460 | ( 'A', 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'::geometry ), 461 | ( 'B', 'POLYGON ((300 200, 400 200, 400 100, 300 100, 300 200))'::geometry ), 462 | ( 'C', 'POLYGON ((100 400, 200 400, 200 300, 100 300, 100 400))'::geometry ), 463 | ( 'AA', 'POLYGON ((120 380, 180 380, 180 320, 120 320, 120 380))'::geometry ), 464 | ( 'BA', 'POLYGON ((110 180, 160 180, 160 130, 110 130, 110 180))'::geometry ), 465 | ( 'BB', 'POLYGON ((170 130, 190 130, 190 110, 170 110, 170 130))'::geometry ), 466 | ( 'CA', 'POLYGON ((330 170, 380 170, 380 120, 330 120, 330 170))'::geometry ), 467 | ( 'AAA', 'POLYGON ((330 170, 380 170, 380 120, 330 120, 330 170))'::geometry ), 468 | ( 'BAA', 'POLYGON ((121 171, 151 171, 151 141, 121 141, 121 171))'::geometry ), 469 | ( 'CAA', 'POLYGON ((341 161, 351 161, 351 141, 341 141, 341 161))'::geometry ), 470 | ( 'CAB', 'POLYGON ((361 151, 371 151, 371 131, 361 131, 361 151))'::geometry ) 471 | ) AS t(id, geom) 472 | ) 473 | SELECT a.id 474 | FROM data AS A 475 | LEFT JOIN data AS b ON a.id <> b.id AND ST_CoveredBy(a.geom, b.geom) 476 | WHERE b.geom IS NULL; 477 | ``` 478 | ### Count Overlap Depth in set of polygons 479 | https://gis.stackexchange.com/questions/159282/counting-overlapping-polygons-in-postgis-using-st-union-very-slow 480 | 481 | Solution 1: 482 | Compute overlay of dataset using ST_Node and ST_Polygonize 483 | Count overlap depth using ST_PointOnSurface and ST_Contains 484 | 485 | ### Identify Overlay Resultant Parentage 486 | 487 | https://gis.stackexchange.com/questions/315368/listing-all-overlapping-polygons-using-postgis 488 | 489 | ### Union of two polygon layers 490 | Wants a coverage overlay (called “QGIS Union”) 491 | https://gis.stackexchange.com/questions/302086/postgis-union-of-two-polygons-layers 492 | 493 | See also 494 | https://gis.stackexchange.com/questions/179533/arcgis-union-equivalent-in-postgis 495 | https://gis.stackexchange.com/questions/115927/is-there-a-union-function-for-multiple-layers-comparable-to-arcgis-in-open-sourc 496 | 497 | 498 | ### Sum of polygonal grid values weighted by area of intersection with polygon 499 | https://gis.stackexchange.com/questions/171333/weighting-amount-of-overlapping-polygons-in-postgis 500 | 501 | ### Sum Percentage of Polygons intersected by other Polygons, by label 502 | 503 | Given two polygonal coverages A and B with labels, compute the percentage area of each polygon in A covered by each label in B 504 | https://gis.stackexchange.com/questions/378532/working-out-percentage-of-polygon-covering-another-using-postgis 505 | 506 | 507 | ![](https://i.stack.imgur.com/bQjSi.png) 508 | 509 | ```sql 510 | WITH poly_a(name, geom) AS (VALUES 511 | ( 'a1', 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'::geometry ), 512 | ( 'a2', 'POLYGON ((300 300, 300 200, 200 200, 200 300, 300 300))'::geometry ), 513 | ( 'a3', 'POLYGON ((400 400, 400 300, 300 300, 300 400, 400 400))'::geometry ) 514 | ), 515 | poly_b(name, geom) AS (VALUES 516 | ( 'b1', 'POLYGON ((120 280, 280 280, 280 120, 120 120, 120 280))'::geometry ), 517 | ( 'b2', 'POLYGON ((280 280, 280 320, 320 320, 320 280, 280 280))'::geometry ), 518 | ( 'b2', 'POLYGON ((390 390, 390 360, 360 360, 360 390, 390 390))'::geometry ) 519 | ) 520 | SELECT a.name, b.name, SUM( ST_Area(ST_Intersection(a.geom, b.geom))/ST_Area(a.geom) ) pct 521 | FROM poly_a a JOIN poly_b b ON ST_Intersects(a.geom, b.geom) 522 | GROUP BY a.name, b.name; 523 | ``` 524 | 525 | 526 | ### Remove Polygons overlapped area on update to Polygon in other table 527 | https://gis.stackexchange.com/questions/90174/postgis-when-i-add-a-polygon-delete-overlapping-areas-in-other-layers 528 | 529 | ### Return only polygons from Overlay 530 | https://gis.stackexchange.com/questions/89231/postgis-st-intersection-of-polygons-can-return-lines 531 | 532 | https://gis.stackexchange.com/questions/242741/st-intersection-returns-erroneous-polygons 533 | 534 | ### Compute Coverage from Overlapping Polygons 535 | https://gis.stackexchange.com/questions/206473/obtaining-each-unique-area-of-overlapping-polygons-in-postgres-9-6-postgis-2-3 536 | 537 | Problem 538 | Reduce a dataset of highly overlapping polygons to a coverage (not clear if attribution is needed or not) 539 | 540 | Issues 541 | User implements a very complex overlay process, but can not get it to work, likely due to robustness problems 542 | 543 | Solution 544 | ST_Boundary -> ST_Union -> ST_Polygonize ?? 545 | 546 | 547 | -------------------------------------------------------------------------------- /pgp-OLD-process.md: -------------------------------------------------------------------------------- 1 | --- 2 | nav_exclude: true 3 | --- 4 | 5 | # Processing 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | 12 | 13 | ## Constructions 14 | 15 | ### Construct polygons filling gaps in a coverage 16 | https://gis.stackexchange.com/questions/368406/postgis-create-new-polygons-in-between-existing 17 | 18 | ```sql 19 | SELECT ST_DIFFERENCE(foo.geom, bar.geom) 20 | FROM (SELECT ST_CONVEXHULL(ST_COLLECT(shape::geometry)) as geom FROM schema.polytable) as foo, 21 | (SELECT ST_BUFFER(ST_UNION(shape),0.5) as geom FROM schema.polytable) as bar 22 | ``` 23 | To scale this up/out, could process batches of polygons using a rectangular grid defined over the data space. The constructed gap polygons can be clipped to grid cells. and optional unioned afterwards 24 | 25 | ### Construct ellipses in WGS84 26 | https://gis.stackexchange.com/questions/218159/postgis-ellipse-issue 27 | 28 | ### Construct polygon joining two polygons 29 | https://gis.stackexchange.com/questions/352884/how-can-i-get-a-polygon-of-everything-between-two-polygons-in-postgis 30 | 31 | ![](https://i.stack.imgur.com/a7idE.png) 32 | 33 | #### Solution 34 | * construct convex hull of both polygons together 35 | * subtract convex hull of each polygon 36 | * union with original polygons 37 | * keep only the polygon shell (remove holes) 38 | 39 | ```sql 40 | WITH data(geom) AS (VALUES 41 | ( 'POLYGON ((100 300, 200 300, 200 200, 100 200, 100 300))'::geometry ) 42 | ,( 'POLYGON ((50 150, 100 150, 100 100, 50 100, 50 150))'::geometry ) 43 | ) 44 | SELECT ST_MakePolygon(ST_ExteriorRing(ST_Union( 45 | ST_Difference( 46 | ST_ConvexHull( ST_Union(geom)), 47 | ST_Union( ST_ConvexHull(geom))), 48 | ST_Collect(geom)))) 49 | FROM data; 50 | ``` 51 | 52 | ### Construct expanded polygons to touches a bounding polygon 53 | https://gis.stackexchange.com/questions/294163/sql-postgis-expanding-polygons-contained-inside-another-polygon-until-one-ver 54 | 55 | ![Expanding polygons to touch](https://i.stack.imgur.com/VQgHj.png) 56 | 57 | ```sql 58 | WITH 59 | to_buffer(distance, b.id) AS ( 60 | SELECT 61 | ST_Distance(ST_Exteriorring(a.geom), b.geom), 62 | b.id 63 | FROM 64 | polygons_outer a, polygons_inner b 65 | WHERE ST_Contains(a.geom, b.geom) 66 | UPDATE polygons_inner b 67 | SET geom = ST_Buffer(geom, distance) 68 | FROM to_buffer tb 69 | WHERE b.id = tb.id; 70 | ``` 71 | See also note about using a scaling rather than buffer, to preserve shape of polygon 72 | 73 | ### Construct Land-Constrained Point Grid 74 | https://korban.net/posts/postgres/2019-10-17-generating-land-constrained-point-grids/ 75 | 76 | ### Construct Square Grid 77 | https://gis.stackexchange.com/questions/16374/creating-regular-polygon-grid-in-postgis 78 | 79 | https://gis.stackexchange.com/questions/4663/how-to-create-regular-point-grid-inside-a-polygon-in-postgis 80 | 81 | https://gis.stackexchange.com/questions/271234/creating-a-grid-on-a-polygon-and-find-number-of-points-in-each-grid 82 | 83 | ### Construct Polygon Centrelines 84 | https://gis.stackexchange.com/questions/322392/average-of-two-lines?noredirect=1&lq=1 85 | 86 | https://gis.stackexchange.com/questions/50668/how-can-i-merge-collapse-nearby-and-parallel-road-lines-eg-a-dual-carriageway 87 | 88 | https://github.com/migurski/Skeletron 89 | 90 | 91 | Idea: triangulate polygon, then connect midpoints of interior lines 92 | 93 | Idea 2: find line segments for nearest points of each line vertex. Order by distance along line (percentage?). Discard any that have a retrograde direction. Join centrepoints of segments. 94 | 95 | ### Construct lines joining every vertex in a polygon 96 | 97 | 98 | 99 | Better answer: 100 | ```sql 101 | WITH poly(id, geom)AS (VALUES 102 | ( 1, 'POLYGON ((2 7, 5 9, 9 7, 8 3, 5 2, 2 3, 3 5, 2 7))'::geometry ) 103 | ) 104 | ,ring AS (SELECT ST_ExteriorRing(geom) geom FROM poly) 105 | ,pts AS (SELECT i, ST_PointN(geom, i) AS geom 106 | FROM ring 107 | JOIN LATERAL generate_series(2, ST_NumPoints(ring.geom)) AS s(i) ON true) 108 | SELECT ST_MakeLine(p1.geom, p2.geom) AS geom 109 | FROM pts p1, pts p2 110 | WHERE p1.i > p2.i; 111 | ``` 112 | 113 | ### Construct Straight Skeleton 114 | 115 | 116 | ## Hulls / Covering Polygons 117 | 118 | ### Construct Bounding box of set of MULTILINESTRINGs 119 | https://gis.stackexchange.com/questions/115494/bounding-box-of-set-of-multilinestrings-in-postgis 120 | ```sql 121 | SELECT type, ST_Envelope(ST_Collect(geom)) 122 | FROM line_table AS foo 123 | GROUP BY type; 124 | ``` 125 | 126 | ### Construct polygon containing lines 127 | https://gis.stackexchange.com/questions/238/find-polygon-that-contains-all-linestring-records-in-postgis-table 128 | 129 | ### Construct lines between all points of a Polygon 130 | https://gis.stackexchange.com/questions/58534/get-the-lines-between-all-points-of-a-polygon-in-postgis-avoid-nested-loop 131 | 132 | ##### Solution 133 | Rework given SQL using CROSS JOIN and a self join 134 | 135 | ### Construct Regions from Points 136 | https://gis.stackexchange.com/questions/92913/extra-detailed-bounding-polygon-from-many-geometric-points 137 | 138 | ### Construct regions from large sets of points (100K) tagged with region attribute. 139 | 140 | Could use ST_ConcaveHull, but results would overlap 141 | Perhaps ST_Voronoi would be better? How would this work, and what are limits on size of data? 142 | 143 | ### Construct a Star Polygon from a set of Points 144 | https://gis.stackexchange.com/questions/349945/creating-precise-shapes-using-list-of-coordinates 145 | 146 | ```sql 147 | WITH pts(pt) AS (VALUES 148 | (st_transform(st_setsrid(st_makepoint(-97.5660461, 30.4894905), 4326),4269) ), 149 | (st_transform(st_setsrid(st_makepoint(-97.5657216, 30.4902173), 4326),4269) ), 150 | (st_transform(st_setsrid(st_makepoint(-97.5608779, 30.4896142), 4326),4269) ), 151 | (st_transform(st_setsrid(st_makepoint(-97.5605001, 30.491422), 4326),4269) ), 152 | (st_transform(st_setsrid(st_makepoint(-97.5588115, 30.4911697), 4326),4269) ), 153 | (st_transform(st_setsrid(st_makepoint(-97.5588262, 30.4910204), 4326),4269) ), 154 | (st_transform(st_setsrid(st_makepoint(-97.5588262, 30.4910204), 4326),4269)), 155 | (st_transform(st_setsrid(st_makepoint(-97.5585742, 30.4909966), 4326),4269)), 156 | (st_transform(st_setsrid(st_makepoint(-97.5578045, 30.4909263), 4326),4269)), 157 | (st_transform(st_setsrid(st_makepoint(-97.5574653, 30.4908877), 4326),4269)), 158 | (st_transform(st_setsrid(st_makepoint(-97.5571534, 30.4908375), 4326),4269)), 159 | (st_transform(st_setsrid(st_makepoint(-97.5560964, 30.4907427), 4326),4269)) 160 | ), 161 | centroid AS (SELECT ST_Centroid( ST_Collect(pt) ) AS centroid FROM pts), 162 | line AS (SELECT ST_MakeLine( pt ORDER BY ST_Azimuth( centroid, pt ) ) AS geom 163 | FROM pts CROSS JOIN centroid), 164 | poly AS (SELECT ST_MakePolygon( ST_AddPoint( geom, ST_StartPoint( geom ))) AS geom 165 | FROM line) 166 | SELECT geom FROM poly; 167 | ``` 168 | 169 | ## Buffers 170 | 171 | ### Variable Width Buffer 172 | https://gis.stackexchange.com/questions/340968/varying-size-buffer-along-a-line-with-postgis 173 | 174 | ### Expand a rectangular polygon 175 | https://gis.stackexchange.com/questions/308333/expanding-polygon-by-distance-using-postgis 176 | 177 | ### Buffer Coastlines with inlet skeletons 178 | https://gis.stackexchange.com/questions/300867/how-can-i-buffer-a-mulipolygon-only-on-the-coastline 179 | 180 | ### Remove Line Buffer artifacts 181 | https://gis.stackexchange.com/questions/363025/how-to-run-a-moving-window-function-in-a-conditional-statement-in-postgis-for-bu 182 | 183 | Quite bizarre, but apparently works. 184 | 185 | 186 | ## Generating Point Distributions 187 | ### Generate Evenly-Distributed Points in a Polygon 188 | 189 | 190 | 191 | One solution: create a grid of points and then clip to polygon 192 | 193 | See also: 194 | * 195 | * 196 | 197 | ### Construct Well-spaced Random Points in a Polygon 198 | 199 | 200 | Uses clustering on randomly generated points. 201 | Suggestion is to use neg-buffered polygon to ensure distance from polygon boundary 202 | 203 | A nicer solution will be when PostGIS provides a way to generate random points using [Poisson Disk Sampling](https://www.jasondavies.com/poisson-disc/). 204 | 205 | ### Place Maximum Number of Points in a Polygon 206 | 207 | 208 | ### Sample Linear Point Clouds at given density 209 | 210 | 211 | ## Contouring 212 | ### Generate contours from evenly-spaced weighted points 213 | https://gis.stackexchange.com/questions/85968/clustering-points-in-postgresql-to-create-contour-map 214 | NO SOLUTION 215 | 216 | ### Contouring Irregularly spaced points 217 | https://abelvm.github.io/sql/contour/ 218 | 219 | Solution 220 | An impressive PostGIS-only solution using a Delaunay with triangles cut by contour lines. 221 | Uses the so-called Meandering Triangles method for isolines. 222 | 223 | ## Surface Interpolation 224 | 225 | ### IDW Interpolation over a grid of points 226 | https://gis.stackexchange.com/questions/373153/spatial-interpolation-in-postgis-without-outputting-raster 227 | 228 | 229 | ## Conflation / Matching 230 | 231 | ### Adjust polygons to fill a containing Polygon 232 | 233 | 234 | ### Match Polygons by Shape Similarity 235 | https://gis.stackexchange.com/questions/362560/measuring-the-similarity-of-two-polygons-in-postgis 236 | 237 | There are different ways to measure the similarity between two polygons such as average distance between the boundaries, Hausdorff distance, Turning Function, Comparing Fourier Transformation of the two polygons 238 | 239 | Gives code for Average Boundary Distance 240 | 241 | ### Find Polygon with more accurate linework 242 | https://gis.stackexchange.com/questions/257052/given-two-polygons-find-the-the-one-with-more-detailed-accurate-shoreline 243 | 244 | ### Match sets of LineStrings 245 | https://gis.stackexchange.com/questions/347787/compare-two-set-of-linestrings 246 | 247 | ### Match paths to road network 248 | https://gis.stackexchange.com/questions/349001/aligning-line-with-closest-line-segment-in-postgis 249 | 250 | ### Match paths 251 | https://gis.stackexchange.com/questions/368146/matching-segments-within-tracks-in-postgis 252 | 253 | ### Polygon Averaging 254 | https://info.crunchydata.com/blog/polygon-averaging-in-postgis 255 | 256 | Solution: Overlay, count “depth” of each resultant, union resultants of desired depth. 257 | 258 | 259 | 260 | 261 | 262 | -------------------------------------------------------------------------------- /pgp-antipattern.md: -------------------------------------------------------------------------------- 1 | # Anti-Patterns 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Using `ST_Distance` OR `ST_Intersects` with `ST_Buffer` for proximity queries 8 | 9 | A simple way to test if geometries are near to (within a distance of) a given geometry is to compute the 10 | buffer of the query geometry and then use `ST_Intersects` against the buffer geometry. However, this is somewhat inaccurate, since buffers are only approximations, and computing large buffers can be slow. 11 | 12 | Another way is to use `ST_Distance`. But this forces the full distance to be computed even though it is not needed. Also, this query does not take advantage of spatial indexes. 13 | 14 | Instead, use `ST_DWithin` instead, since it is automatically indexed, is faster to compute, and is more accurate. 15 | (it avoids having to compute the explicit buffer, which is only a close approximiation of the true distance). 16 | 17 | ## Using `ST_Contains/ST_Within` instead of `ST_Covers/ST_CoveredBy` 18 | 19 | `ST_Contains` and `ST_Within` have a subtle quirk in their definition. It includes the requirement that at least one Interior point must be in common. This means that "Polygons do not contain their boundary". The result is that points and lines in the boundary of a polygon are not contained by/are not within the polygon. `ST_Covers` and `ST_CoveredBy` do not have this semantic peculiarity (and may be faster to execute as well). 20 | 21 | ## Using `NOT IN` or `COUNT <...` instead of `NOT EXISTS` 22 | 23 | This anti-pattern occurs when querying to find rows which are **not** in a given set of other rows 24 | (which may be in the same table or a different one). 25 | 26 | Do not use `NOT IN subquery`, since it forces the subquery to compute the entire set of rows which do not match. 27 | 28 | Instead, use the SQL *anti-join* pattern (see this [blog post](https://www.crunchydata.com/blog/rise-of-the-anti-join)). 29 | This uses `NOT EXISTS subquery` to allow the query engine to short-circuit the subquery evaluation if a match is found. 30 | 31 | ## Using `ST_MakePoint` or `ST_PointFromText` instead of `ST_Point` 32 | 33 | `ST_Point` (and variants) is the standard function to use. 34 | `ST_MakePoint` is obsolete. 35 | They are both much faster than `ST_PointFromText`. 36 | -------------------------------------------------------------------------------- /pgp-clean.md: -------------------------------------------------------------------------------- 1 | # Validation and Cleaning 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Constraint to Validate Geometry column 8 | 9 | 10 | 11 | ```sql 12 | ALTER TABLE public.my_valid_table 13 | ADD CONSTRAINT enforce_valid_geom CHECK (st_isvalid(geom)); 14 | ``` 15 | 16 | ## Remove Ring Self-Intersections / MakeValid 17 | 18 | The question and standard answer (buffer(0) are fairly mundane. But note the answer where the user uses MakeValid and keeps only the result polygons with significant area. Might be a good option to MakeValid? 19 | 20 | ## Remove Slivers 21 | 22 | 23 | ## Remove Slivers after union of non-vector clean Polygons 24 | 25 | 26 | Gives outline for function `cleanPolygon` but does not provide source 27 | 28 | ## Remove Spikes 29 | 30 | 31 | ![](https://i.stack.imgur.com/iCRwL.png) 32 | 33 | **Solutions** 34 | 35 | Some custom code implementations: 36 | 37 | 38 | 39 | 40 | 41 | ## Remove vertices along straight edges 42 | 43 | 44 | ![](https://i.stack.imgur.com/GQB3b.jpg) 45 | 46 | **Solution** 47 | 48 | * Simplify the polygon with a very small distance tolerance, using one of: 49 | * [`ST_Simplify`](https://postgis.net/docs/manual-3.3/ST_Simplify.html) 50 | * [`ST_SimplifyPreserveTopology`](https://postgis.net/docs/manual-3.3/ST_SimplifyPreserveTopology.html) 51 | * [`ST_SimplifyVW`](https://postgis.net/docs/manual-3.3/ST_SimplifyVW.html) 52 | * [`ST_SimplifyPolygonHull`](https://postgis.net/docs/manual-3.3/ST_SimplifyPolygonHull.html) 53 | -------------------------------------------------------------------------------- /pgp-coverage.md: -------------------------------------------------------------------------------- 1 | # Polygonal Coverages 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Find Overlaps 8 | 9 | **Solution** 10 | Find pairs of polygons whose interiors intersect. 11 | 12 | ```sql 13 | SELECT ST_CollectionExtract( ST_Intersection( a.geom, b.geom), 3))) AS overlap 14 | FROM polycov a 15 | JOIN polycov b 16 | ON ST_Intersects(a.geom, b.geom) 17 | WHERE ST_Relate(a.geom, b.geom, '2********') 18 | AND a.id > b.id 19 | ``` 20 | 21 | ## Find Gaps/Slivers 22 | 23 | **Solution** 24 | * Union the polygons in the coverage 25 | * Find result union polygons containing holes 26 | * Extract the holes as polygons 27 | 28 | ```sql 29 | WITH union AS ( 30 | SELECT (ST_DUMP(ST_Union(geom))).geom as geom 31 | FROM polycov As f 32 | ), 33 | hasgaps AS ( 34 | SELECT geom 35 | FROM union 36 | WHERE ST_NumInteriorRings(geom) > 0 37 | ), 38 | SELECT ST_CollectionExtract(ST_BuildArea(ST_InteriorRingN(geom, i)), 3) as gap 39 | FROM hasgaps 40 | CROSS JOIN generate_series(1, ST_NumInteriorRings(geom)) as i 41 | ``` 42 | 43 | ## Create trigger to enforce no overlaps 44 | 45 | 46 | Uses `ST_Relate(my_data.geom, g, '2********'))`. 47 | 48 | ```sql 49 | CREATE TABLE my_data ( 50 | id int PRIMARY KEY, 51 | geom geometry 52 | ); 53 | 54 | CREATE INDEX ON my_data USING gist(geom); 55 | 56 | CREATE FUNCTION no_overlaps_in_my_data(id int, g geometry) 57 | RETURNS boolean AS $$ 58 | SELECT NOT EXISTS ( 59 | SELECT 1 FROM my_data 60 | WHERE my_data.id != id 61 | AND my_data.geom && g 62 | AND ST_Relate(my_data.geom, g, '2********')); 63 | $$ LANGUAGE sql; 64 | 65 | ALTER TABLE my_data ADD CONSTRAINT no_overlaps CHECK (no_overlaps_in_my_data(id, geom)); 66 | 67 | ``` 68 | 69 | Test: 70 | ```sql 71 | INSERT INTO my_data VALUES (1, ST_Buffer(ST_MakePoint(1, 1), 1)); 72 | -- OK 73 | INSERT INTO my_data VALUES (2, ST_Buffer(ST_MakePoint(3, 1), 1)); 74 | -- OK 75 | INSERT INTO my_data VALUES (3, ST_Buffer(ST_MakePoint(2, 1), 1)); 76 | -- ERROR: new row for relation "my_data" violates check constraint "no_overlaps" 77 | ``` 78 | -------------------------------------------------------------------------------- /pgp-create.md: -------------------------------------------------------------------------------- 1 | # Create, Access, Edit 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Geometry Creation 8 | 9 | ### Use `ST_Point` instead of `ST_MakePoint` or `ST_PointFromText` 10 | 11 | 12 | 13 | 14 | **Solution** 15 | 16 | `ST_Point` (and variants) is the standard function to use. 17 | `ST_MakePoint` is obsolete. 18 | They are both much faster than `ST_PointFromText`. 19 | 20 | ### Collect Lines into a MultiLine in a given order 21 | 22 | 23 | Input: 24 | ![](https://i.stack.imgur.com/Oc7AG.png) 25 | 26 | Ordering from plain `ST_Collect`: 27 | ![](https://i.stack.imgur.com/mRuXi.png) 28 | 29 | **Solution** 30 | 31 | Use aggregate `ORDER BY`: 32 | 33 | ```sql 34 | SELECT ST_Collect(geom ORDER BY seq_num)) FROM lines; 35 | ``` 36 | 37 | ### Create Line Segments from ordered Point records 38 | 39 | 40 | **Solution** 41 | Use `LEAD` window function: 42 | ```sql 43 | WITH src (id, dtt, geom) AS (VALUES 44 | (1,1,'POINT (1 1)'), 45 | (1,2,'POINT (1 2)'), 46 | (1,3,'POINT (1 3)'), 47 | (2,1,'POINT (2 1)'), 48 | (2,2,'POINT (2 2)'), 49 | (2,3,'POINT (1 3)')) 50 | SELECT id, dtt, ST_AsText( 51 | ST_MakeLine(geom, LEAD(geom) OVER(PARTITION BY id ORDER BY dtt))) AS geom 52 | FROM src; 53 | ``` 54 | 55 | ## Geometry Access 56 | 57 | ### Extract shells and holes from MultiPolygons 58 | 59 | 60 | **Solution** 61 | 62 | A solution using: 63 | 64 | * `generate_series` to extract the polygons (avoids having to deal with the recordset returned from `ST_Dump`) 65 | * SQL aggregate `FILTER` clauses to separate the shells and holes from the dumped rings 66 | 67 | ```sql 68 | WITH multipoly(geom) AS (VALUES 69 | ('MULTIPOLYGON (((10 10, 10 90, 70 90, 10 10), (20 80, 40 70, 40 80, 20 80), (20 70, 40 60, 20 40, 20 70)), ((50 30, 80 60, 80 30, 50 30)))'::geometry) 70 | ), 71 | rings AS ( 72 | SELECT (r.dumped).geom AS geom, 73 | ((r.dumped).path)[1] AS loc 74 | FROM (SELECT ST_DumpRings( 75 | ST_GeometryN(geom, 76 | generate_series(1, 77 | ST_NumGeometries( geom )))) AS dumped 78 | FROM multipoly) AS r 79 | ) 80 | SELECT ST_Collect( geom ) FILTER (WHERE loc = 0) AS shells, 81 | ST_Collect( geom ) FILTER (WHERE loc > 0) AS holes 82 | FROM rings; 83 | ``` 84 | 85 | ## Geometry Editing 86 | 87 | ### Remove Holes from Polygons 88 | 89 | ```sql 90 | SELECT CASE 91 | WHEN ST_NRings(geom) > 1 92 | THEN ST_MakePolygon(ST_ExteriorRing(geom)) 93 | ELSE geom 94 | END AS geom 95 | FROM polys; 96 | ``` 97 | 98 | ### Remove Holes from MultiPolygons 99 | 100 | 101 | **Solution** 102 | 103 | 104 | * Use `ST_Dump` to explode the MultiPolygon into separate Polygons 105 | * use `ST_MakePolygon(ST_ExteriorRing(poly))` to remove the holes from each element Polygon 106 | * Use `ST_Collect` to recombine the hole-free elements 107 | 108 | ```sql 109 | WITH data AS ( 110 | SELECT 'MULTIPOLYGON (((90 240, 260 240, 260 100, 90 100, 90 240), (130 200, 200 200, 200 140, 130 140, 130 200)), ((290 240, 380 240, 380 170, 290 170, 290 240), (324 216, 360 216, 360 180, 324 180, 324 216)), ((310 140, 375 140, 375 91, 310 91, 310 140)))'::geometry AS geom 111 | ), 112 | polys AS ( 113 | SELECT (ST_Dump( geom )).geom FROM data 114 | ), 115 | polynoholes AS ( 116 | SELECT ST_Collect( ST_MakePolygon( ST_ExteriorRing( geom ))) FROM polys 117 | ) 118 | SELECT * FROM polynoholes 119 | ``` 120 | 121 | **Similar** 122 | 123 | 124 | ### Remove Small Holes from MultiPolygons 125 | 126 | 127 | Remove holes below a given area from a table of MultiPolygons. 128 | 129 | **Solution** 130 | In this example the size limit is 100. Note that it works for Polygons as well. 131 | 132 | ```sql 133 | WITH data(id, geom) AS (VALUES 134 | (1, 'MULTIPOLYGON (((100 100, 100 0, 0 0, 0 100, 100 100), (10 10, 10 70, 60 10, 10 10), (30 90, 90 90, 90 30, 30 90), (20 80, 10 80, 10 90, 20 80), (90 10, 80 10, 80 20, 90 10)), ((0 170, 100 170, 100 120, 0 120, 0 170), (10 130, 10 140, 20 130, 10 130)))'::geometry) 135 | ,(2, 'MULTIPOLYGON (((200 100, 300 100, 300 0, 200 0, 200 100), (210 10, 210 70, 260 10, 210 10), (280 80, 280 90, 290 80, 280 80)), ((200 160, 260 160, 260 120, 200 120, 200 160)))'::geometry) 136 | ,(3, 'POLYGON ((110 90, 190 90, 190 10, 110 10, 110 90), (120 20, 120 80, 180 20, 120 20), (170 70, 170 80, 180 70, 170 70))'::geometry) 137 | ) 138 | SELECT id, ST_Collect( 139 | ARRAY( SELECT ST_MakePolygon( 140 | ST_ExteriorRing(geom), 141 | ARRAY( SELECT ST_ExteriorRing( rings.geom ) 142 | FROM ST_DumpRings(geom) AS rings 143 | WHERE rings.path[1] > 0 144 | AND ST_Area( rings.geom ) >= 100 ) 145 | ) 146 | FROM ST_Dump(geom) AS poly ) 147 | ) AS geom 148 | FROM data; 149 | ``` 150 | As a function: 151 | ```sql 152 | CREATE OR REPLACE FUNCTION ST_RemoveHolesByArea( 153 | geom GEOMETRY, 154 | area real) 155 | RETURNS GEOMETRY AS 156 | $BODY$ 157 | WITH 158 | tbla AS (SELECT ST_Dump(geom)) 159 | SELECT ST_Collect(ARRAY(SELECT ST_MakePolygon(ST_ExteriorRing(geom), 160 | ARRAY(SELECT ST_ExteriorRing(rings.geom) FROM ST_DumpRings(geom) AS rings 161 | WHERE rings.path[1]>0 AND ST_Area(rings.geom)>=area)) 162 | FROM ST_Dump(geom))) AS geom FROM tbla; 163 | $BODY$ 164 | LANGUAGE SQL; 165 | ``` 166 | -------------------------------------------------------------------------------- /pgp-geography.md: -------------------------------------------------------------------------------- 1 | # Geography 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Segmentize lines for accurate area computation 8 | 9 | 10 | The problem: calculating the area of a large polygon with straight lines that is converted to a `geography`. 11 | 12 | Use `ST_Segmentize` to add intermediary segments in the lines. This provides a better representation of the geodesic lines in geography. 13 | 14 | ```sql 15 | WITH data(geom) AS (VALUES 16 | ( ST_GeomFromEWKT('SRID=4326;POLYGON ((-125 49, -67 49, -67 25, -125 25, -125 49))') ) 17 | ) 18 | SELECT ST_Area( ST_Segmentize( geom, 0.1)::geography ) AS segarea, 19 | ST_Area( geom::geography ) AS area 20 | FROM data; 21 | ``` 22 | 23 | ## Find geometry with invalid geodetic coordinates 24 | 25 | 26 | **Example** 27 | ```sql 28 | SELECT ST_Transform(ST_SetSRID('POINT(575 90)'::geometry,4269),102008); 29 | 30 | ERROR: transform: latitude or longitude exceeded limits (-14) 31 | ``` 32 | 33 | **Find geodetic data with invalid coordinates** 34 | ```sql 35 | SELECT * FROM data_tbl 36 | WHERE abs(ST_XMax(geom)) > 180 37 | OR abs(ST_YMax(geom) > 90; 38 | ``` 39 | 40 | ## Find geodetic Spatial Reference System definitions 41 | 42 | ```sql 43 | SELECT srid, srtext 44 | FROM spatial_ref_sys 45 | WHERE srtext LIKE 'GEO%'; 46 | ``` 47 | -------------------------------------------------------------------------------- /pgp-group.md: -------------------------------------------------------------------------------- 1 | # Grouping, Clustering 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Grouping 8 | 9 | ### Group touching Polygons 10 | 11 | 12 | ![](https://i.stack.imgur.com/YkIn5.jpg) 13 | 14 | 15 | **Solution** 16 | Use `ST_ClusterDBSCAN`, which provides very good performance. 17 | 18 | ```sql 19 | SELECT *, 20 | ST_ClusterDBSCAN(geom, 0, 1) OVER() AS clst_id 21 | FROM poly_tbl; 22 | ``` 23 | 24 | This problem has a similar recommended solution: 25 | 26 | 27 | A worked example: 28 | 29 | 30 | An alernate solution using recursive CTE and ST_DWithin?: 31 | 32 | 33 | Similar problem in R 34 | 35 | 36 | **Issues** 37 | 38 | * DBSCAN uses distance. This will also cluster polygons which touch only at a point, not just along an edge. Is there a way to improve this? Allow a different distance metric perhaps - say length of overlap? 39 | 40 | ### Grouping Intersecting Polygons 41 | 42 | 43 | 44 | 45 | **Solutions** 46 | The query `data` is example data. 47 | 48 | Using `ST_ClusterDBSCAN` with `eps => 0`: 49 | 50 | ```sql 51 | WITH data(fid, class, geom) AS ( 52 | SELECT ROW_NUMBER() OVER (), 53 | CASE x WHEN 5 THEN 1 ELSE x END AS class, 54 | ST_Buffer(ST_Point(x, 1.5 * y), 0.6, 2) AS geom 55 | FROM generate_series(1, 10) AS s1(y) 56 | CROSS JOIN generate_series(1, 10) AS s2(x) 57 | ), 58 | clust AS ( 59 | SELECT ST_ClusterDBSCAN(geom, 0, 2) OVER () AS clustid, fid, class, geom 60 | FROM data WHERE class IN (1, 2, 3) 61 | ) 62 | SELECT * FROM clust WHERE clustid IS NOT NULL; 63 | ``` 64 | 65 | Using `ST_ClusterIntersectingWin`: 66 | ```sql 67 | WITH data(fid, class, geom) AS ( 68 | SELECT ROW_NUMBER() OVER (), 69 | CASE x WHEN 5 THEN 1 ELSE x END AS class, 70 | ST_Buffer(ST_Point(x, 1.5 * y), 0.6, 2) AS geom 71 | FROM generate_series(1, 10) AS s1(y) 72 | CROSS JOIN generate_series(1, 10) AS s2(x) 73 | ), 74 | datasel AS ( 75 | SELECT * FROM data WHERE class IN (1, 2, 3) 76 | ), 77 | clust AS ( 78 | SELECT ST_ClusterIntersectingWin(geom) OVER () AS clustid, fid, class, geom FROM datasel 79 | ), 80 | clustercnt AS ( 81 | SELECT clustid, COUNT(*) AS cnt FROM clust GROUP BY clustid 82 | ) 83 | SELECT fid, class, geom FROM clust c 84 | JOIN clustercnt cs ON c.clustid = cs.clustid 85 | WHERE cnt > 1; 86 | ``` 87 | 88 | 89 | ### Group connected LineStrings 90 | 91 | 92 | ![](https://i.stack.imgur.com/WNlxX.png) 93 | 94 | Presents a recursive CTE approach, but ultimately recommends using `ST_ClusterDBCSAN` or `ST_ClusterIntersecting`. 95 | 96 | ### Group LineStrings via connectivity and attribute 97 | 98 | 99 | ![](https://i.stack.imgur.com/SFl4X.png) 100 | 101 | Use `ST_ClusterIntersecting`: 102 | ```sql 103 | SELECT attr, unnest(ST_ClusterIntersecting(geom)) 104 | FROM lines 105 | GROUP by attr; 106 | ``` 107 | 108 | ### Group Polygon Coverage into similar-sized Areas 109 | 110 | 111 | More generally: how to group adjacent polygons into sets with similar sum of a given attribute. 112 | 113 | See Also 114 | 115 | 116 | Solution 117 | Build adjacency graph and aggregate based on total, and perhaps some distance criteria? 118 | Note: posts do not provide a PostGIS solution for this. Not known if such a solution exists. 119 | Would need a recursive query to do this. 120 | How to keep clusters compact? 121 | 122 | ### GROUP BY keeping one Geometry 123 | 124 | 125 | Using `FIRST_VALUE` window function: 126 | ```sql 127 | SELECT DISTINCT col, 128 | FIRSET_VALUE(geom) OVER (PARTITION BY col ORDER BT dt) 129 | FROM t; 130 | ``` 131 | Using `ARRAY_AGG` approach: 132 | ```sql 133 | SELECT col, 134 | (ARRAY_AGG(geo ORDER BY dt))[1] 135 | FROM t GROUP BY col 136 | ``` 137 | ### Group points by attribute and compute a centroid for each group 138 | 139 | 140 | Use `ST_Collect` with `ST_Centroid` or `ST_GeometricMedian`: 141 | ```sql 142 | SELECT village, ST_Centroid(ST_Collect(geom)) AS geom FROM your_table GROUP BY village; 143 | ``` 144 | 145 | ## Clustering 146 | See 147 | for a variety of approaches that predate a lot of the PostGIS clustering functions. 148 | 149 | ### Grid-Based Clustering 150 | 151 | 152 | **Solution 1** 153 | 154 | Use [`ST_SnapToGrid`](https://postgis.net/docs/manual-3.5/ST_SnapToGrid.html) to compute a cell id for each point, then group the points based on that. Can use aggregate function to count points in grid cell, or use DISTINCT ON as a way to pick one representative point. Need to use representative point rather than average, for better visual results (perhaps?) 155 | 156 | ```sql 157 | SELECT id, pt FROM ( 158 | SELECT DISTINCT ON (snap) 159 | id, pt, 160 | ST_SnapToGrid(pt, 1) AS snap 161 | FROM points 162 | ) AS t; 163 | ``` 164 | 165 | **Solution 2** 166 | 167 | Generate grid of cells covering desired area, then `JOIN LATERAL` to points to aggregate. Not sure how to select a representative point doing this though - perhaps MIN or MAX? Requires a grid-generating function, which is coming in PostGIS 3.1 168 | 169 | ### Clustering Points using DBSCAN 170 | 171 | Cluster a selection of points using DBSCAN, and return centroid of cluster and count of points. 172 | 173 | 174 | 175 | ```sql 176 | WITH pts AS ( 177 | SELECT (ST_DumpPoints(ST_GeneratePoints('POLYGON ((10 90, 90 90, 90 10, 10 10, 10 90))', 100, 2))).geom AS geom 178 | ) 179 | SELECT x.cid, ST_Centroid(ST_Collect(x.geom)) geom, COUNT(cid) num_points FROM 180 | ( 181 | SELECT ST_ClusterDBSCAN(geom, eps := 8, minpoints := 2) over () AS cid, geom 182 | FROM pts 183 | GROUP BY(geom) 184 | ) as x 185 | WHERE cid IS NOT NULL 186 | GROUP BY x.cid ORDER BY cid; 187 | ``` 188 | 189 | ![](https://i.stack.imgur.com/auPHl.jpg) 190 | 191 | ### Non-spatial clustering by distance 192 | 193 | 194 | ### Find Density Centroids Within Polygons 195 | 196 | 197 | 198 | ### Kernel Density 199 | 200 | 201 | ### Bottom-Up Clustering Algorithm 202 | Not sure if this is worthwhile or not. Possibly superseded by more recent standard PostGIS clustering functions 203 | 204 | 205 | 206 | ### Using ClusterWithin VS ClusterDBSCAN 207 | 208 | 209 | Explains how DBSCAN is a superset of `ST_ClusterWithin`, and provides simpler, more powerful SQL. 210 | 211 | 212 | ### Removing Clusters of Points 213 | 214 | 215 | ### Cluster with DBSCAN partitioned by polygons 216 | 217 | 218 | ### FInd polygons which are not close to any other polygon 219 | 220 | 221 | Solution 222 | Use `ST_GeometricMedian` 223 | 224 | ### Cluster with DBSCAN partitioned by record types 225 | 226 | 227 | ### Select evenly-distributed points of unevenly-distributed set, with priority 228 | 229 | 230 | ### Construct K-Means clusters for each Polygon 231 | 232 | 233 | ![](https://i.stack.imgur.com/eFj0g.png) 234 | 235 | Use the `ST_ClusterKMeans` window function with `PARTITION BY`. 236 | 237 | `ST_ClusterKMeans` computes cluster ids 0..n for each (hierarchy of) partition key(s) used in the PARTITION BY expression. 238 | 239 | To compute clusters for each set of points in each polygon (assuming each polygon has id `poly_id`): 240 | 241 | ```sql 242 | WITH polys(poly_id, geom) AS ( 243 | VALUES (1, 'POLYGON((0 0, 0 5, 5 5, 5 0, 0 0))'::GEOMETRY), 244 | (2, 'POLYGON((10 10, 10 15, 15 15, 15 10, 10 10))'::GEOMETRY) 245 | ) 246 | SELECT polys.poly_id, 247 | ST_ClusterKMeans(pts.geom, 4) OVER(PARTITION BY polys.poly_id) AS cluster_id, 248 | pts.geom 249 | FROM polys, 250 | LATERAL ST_Dump(ST_GeneratePoints(polys.geom, 1000, 1)) AS pts 251 | ORDER BY 1, 2; 252 | ``` 253 | ![](https://i.stack.imgur.com/3Tz4X.png) 254 | 255 | 256 | -------------------------------------------------------------------------------- /pgp-intro.md: -------------------------------------------------------------------------------- 1 | --- 2 | nav_order: 1 3 | --- 4 | 5 | # PostGIS Patterns 6 | 7 | A compendium of PostGIS problems, patterns, and solutions. 8 | 9 | The information is drawn from various sources including: 10 | 11 | * [PostGIS on GIS StackExchange](https://gis.stackexchange.com/questions/tagged/postgis?tab=Newest) 12 | * [PostGIS on StackOverflow](https://stackoverflow.com/questions/tagged/postgis) 13 | * [PostGIS Manual 3.0](https://postgis.net/docs/manual-3.0/index.html) 14 | * [PostGIS Users Wiki - Examples of Spatial SQL](https://trac.osgeo.org/postgis/wiki/UsersWikiMain#ExamplesofSpatialSQL) 15 | 16 | 17 | 18 | 19 | -------------------------------------------------------------------------------- /pgp-io.md: -------------------------------------------------------------------------------- 1 | 2 | # Input/Output 3 | {: .no_toc } 4 | 5 | 1. TOC 6 | {:toc} 7 | 8 | ## Input 9 | 10 | ### Parse Error loading OSM Polygons 11 | 12 | 13 | #### Solution 14 | Problem is incorrect order of columns, so trying to load an integer into a geometry field. 15 | Better error messages would make this more obvious. 16 | 17 | ### Parse Error from non-WKT format text 18 | 19 | 20 | ## GeoJSON 21 | 22 | ### Generate GeoJSON Feature 23 | 24 | 25 | ```sql 26 | SELECT jsonb_build_object( 27 | 'type', 'Feature', 28 | 'id', gid, 29 | 'geometry', ST_AsGeoJSON(geom)::jsonb, 30 | 'properties', to_jsonb(row) - 'gid' - 'geom' 31 | ) FROM (SELECT * FROM input_table) row; 32 | ``` 33 | 34 | ### Generate GeoJSON FeatureCollection 35 | 36 | 37 | ```sql 38 | SELECT jsonb_build_object( 39 | 'type', 'FeatureCollection', 40 | 'features', jsonb_agg(features.feature) 41 | ) 42 | FROM ( 43 | SELECT jsonb_build_object( 44 | 'type', 'Feature', 45 | 'id', gid, 46 | 'geometry', ST_AsGeoJSON(geom)::jsonb, 47 | 'properties', to_jsonb(inputs) - 'gid' - 'geom' 48 | ) AS feature 49 | FROM (SELECT * FROM input_table) inputs) features; 50 | ``` 51 | 52 | ### Generate GeoJSON Features for geometry bounds 53 | 54 | 55 | ```sql 56 | SELECT JSONB_BUILD_OBJECT( 57 | 'type', 'FeatureCollection', 58 | 'features', JSONB_AGG(ST_AsGeoJSON(q.*)::JSONB) 59 | ) AS fc 60 | FROM ( 61 | SELECT 1 AS id, 62 | ST_Envelope(ST_Expand('POINT(0 0)'::GEOMETRY, 1)) AS geom 63 | ) q; 64 | ``` 65 | 66 | ### Custom aggregate functions for GeoJSON FeatureCollections 67 | 68 | ```sql 69 | SELECT ST_AsFeatureCollection(q.*) AS geojson 70 | FROM ( 71 | SELECT 1 AS id, 72 | ST_Envelope(ST_Expand('POINT(0 0)'::GEOMETRY, 1)) AS geom 73 | ) q; 74 | ``` 75 | -------------------------------------------------------------------------------- /pgp-measure.md: -------------------------------------------------------------------------------- 1 | # Measuring, Ordering 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Measuring 8 | 9 | ### Find Median width of Road Polygons 10 | 11 | 12 | ### Unbuffering - find average distance from a buffer and source polygon 13 | 14 | 15 | Also: 16 | 17 | ### Compute Length and Width of an arbitrary rectangle 18 | 19 | 20 | ### Convert distance to geodetic degrees 21 | 22 | 23 | **Solution** 24 | 25 | Geodetic distance depends on the latitude of the initial point and the azimuth (bearing). 26 | 27 | ```sql 28 | WITH pt AS (SELECT 5 AS long, 40 AS lat) 29 | SELECT 30 | 1 / ST_Distance( 31 | ST_Point(pt.long, pt.lat)::geography, 32 | ST_Point(pt.long, pt.lat + 1)::geography 33 | ) AS one_meter_lat_north, 34 | 1 / ST_Distance( 35 | ST_Point(pt.long, pt.lat)::geography, 36 | ST_Point(pt.long + 1, pt.lat)::geography 37 | ) AS one_meter_long_east 38 | FROM pt; 39 | ``` 40 | 41 | **Solution 2** 42 | 43 | ```sql 44 | /* 45 | * Returns a close approximation of distance in degrees of a sphere at given @latitude that corresponds to 46 | * @distance meter surface distance, in the direction of north based @angle in degree, from the center of the ellipse. 47 | * Angularity defaults to 90.0 (eastward) and shortcuts execution - corresponds to the simple factor of 48 | * reduced surface distance per degree of longitude at increasing latitudes. 49 | */ 50 | 51 | CREATE OR REPLACE FUNCTION ST_ToGeodeticDegrees( 52 | latitude FLOAT, 53 | distance FLOAT, 54 | angle FLOAT DEFAULT 90.0 55 | ) RETURNS FLOAT IMMUTABLE STRICT PARALLEL SAFE 56 | LANGUAGE 'plpgsql' AS 57 | $BODY$ 58 | DECLARE 59 | ld FLOAT := $2 / DEGREE(6371000.0 * COS(RADIANS($1))) 60 | 61 | BEGIN 62 | IF $3 IN (90.0, 180.0) THEN 63 | RETURN ld; 64 | END IF; 65 | 66 | RETURN SQRT(POW(ld, 2) * POW(COS(RADIANS($3)), 2) + POW(SIN(RADIANS($3)), 2)); 67 | END; 68 | $BODY$ 69 | ; 70 | ``` 71 | 72 | ### Convert bearing to Cardinal Direction 73 | * 74 | * 75 | 76 | Converts a bearing from `ST_Azimuth` to a cardinal direction (N, NW, W, SW, S, SE, E, or NE). 77 | 78 | ```sql 79 | CREATE OR REPLACE FUNCTION ST_CardinalDirection(azimuth float8) RETURNS character varying AS 80 | $BODY$SELECT CASE 81 | WHEN $1 < 0.0 THEN 'less than 0' 82 | WHEN degrees($1) < 22.5 THEN 'N' 83 | WHEN degrees($1) < 67.5 THEN 'NE' 84 | WHEN degrees($1) < 112.5 THEN 'E' 85 | WHEN degrees($1) < 157.5 THEN 'SE' 86 | WHEN degrees($1) < 202.5 THEN 'S' 87 | WHEN degrees($1) < 247.5 THEN 'SW' 88 | WHEN degrees($1) < 292.5 THEN 'W' 89 | WHEN degrees($1) < 337.5 THEN 'NW' 90 | WHEN degrees($1) <= 360.0 THEN 'N' 91 | END;$BODY$ LANGUAGE sql IMMUTABLE COST 100; 92 | COMMENT ON FUNCTION ST_CardinalDirection(float8) IS 'input azimuth in radians; returns N, NW, W, SW, S, SE, E, or NE'; 93 | ``` 94 | 95 | ## Ordering Polygons 96 | 97 | ### Ordering a Square Grid 98 | 99 | 100 | 101 | 102 | ### Serpentine Ordering 103 | 104 | 105 | No solution in the post 106 | 107 | Also 108 | 109 | 110 | ## Ordering Polygons Along Lines 111 | 112 | ### Ordering Polygons along a line 113 | 114 | 115 | No explicit solution given, but suggestion is to compute adjacency graph and then do a graph traversal 116 | 117 | ### Order polygons touched by a Line 118 | 119 | 120 | ### Connecting Circles Into a Polygonal Path 121 | 122 | 123 | ### Ordered list of polygons intersecting a line 124 | 125 | 126 | ## Ordering Lines Along a Path 127 | 128 | ### Ordering Connected Lines Along a Path 129 | 130 | If lines are known to be connected, then: 131 | * use `ST_LineMerge` to produce a single continguous line 132 | * use `ST_LineLocatePoint` to produce fractional distance of midpoint of each line 133 | * order lines by fractional distance 134 | 135 | ### Ordering Disconnected Lines Along a Path 136 | 137 | Would be useful to have a window function `ST_LineOrder` to produce a ordering index of a set of disconnected lines. 138 | 139 | 140 | ## Ordering Points along Lines 141 | 142 | ### Ordering points along lines 143 | 144 | Given: 145 | * way (id, name, geom (multistring)) 146 | * station (id, name, geom (polygon)) - circles for each station, which may or may not intersect way line 147 | 148 | Find the station order along each way 149 | 150 | 151 | 152 | The first step is to replace the station polygons by points (i.e. use centroid) 153 | 154 | ```sql 155 | WITH 156 | dumped_ways AS ( 157 | SELECT way_name, 158 | dmp.path[1] AS way_part, 159 | dmp.geom 160 | FROM s_602_ptrc.way, 161 | LATERAL ST_Dump(geom) AS dmp 162 | ) 163 | 164 | SELECT ROW_NUMBER() OVER(PARTITION BY nway.way_name, nway.way_part ORDER BY nway._frac) AS id, 165 | station.nome AS station, 166 | nway.way_name, 167 | nway.way_part, 168 | station.geom 169 | FROM s_602_ptrc.station 170 | CROSS JOIN LATERAL ( 171 | SELECT dumped_ways.way_name, 172 | dumped_ways.way_part, 173 | ST_LineLocatePoint(dumped_ways.geom, station.geom) AS _frac 174 | FROM dumped_ways 175 | ORDER BY 176 | dumped_ways.geom <-> ST_Centroid(station.geom) 177 | LIMIT 1 178 | ) AS nway 179 | ORDER BY nway.way_name, nway.way_part, nway._frac; 180 | ``` 181 | -------------------------------------------------------------------------------- /pgp-transform.md: -------------------------------------------------------------------------------- 1 | # Transform 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Transformation 8 | 9 | ### Scale polygon around a given point 10 | 11 | 12 | No solution so far 13 | Issues 14 | SQL given is overly complex and inefficient. But idea is right 15 | 16 | ## Simplification 17 | 18 | 19 | ## Smoothing 20 | 21 | 22 | Problem is to smooth a network of lines. Network is not fully noded, so smoothing causes touching lines to become disconnected. 23 | #### Solution 24 | Probably to node the network before smoothing. 25 | Not sure how to node the network and preserve IDs however!? 26 | 27 | ## Coordinate Systems 28 | 29 | ### Find a planar projection for geodetic data 30 | 31 | 32 | Also 33 | 34 | ### ST_Transform creates invalid geometry 35 | 36 | 37 | Also: 38 | Has an example geometry which becomes invalid when transformed from SRID 3857 to 4326. 39 | ```sql 40 | WITH sample AS ( 41 | 42 | SELECT ST_GeomFromText('MULTIPOLYGON(((2382720.17390635 9089461.95191981,2382367.6918707 9089034.6330938,2383639.33894183 9088936.19228217,2383491.66250535 9088320.85158849,2382449.73433542 9088378.30497631,2382055.93050479 9088845.95402014,2381571.89109492 9088566.99620937,2382909.16100587 9087525.07043225,2383385.00730122 9087713.76366274,2382367.6918707 9086433.9341019,2383007.61196353 9086589.80403919,2382892.75251293 9086056.52215661,2383387.76802459 9086009.53671596,2384109.85303357 9086307.94844515,2383500.05599495 9084868.129924,2384106.96985876 9084899.76660559,2383959.29342227 9083792.17446382,2384344.89300643 9083513.24218185,2383385.00730122 9082274.42190291,2382950.18223823 9082971.7746775,2381932.87793967 9082873.34378008,2382088.74749067 9084563.39240152,2382671.24899015 9084481.35648623,2382310.2621454 9085268.94495686,2381481.64438374 9084021.89443657,2381875.44821437 9082331.85126724,2382523.57255366 9081798.56835936,2381982.09228655 9079919.82309238,2381916.46944672 9081101.23196672,2381645.72931316 9081019.18678447,2381350.37644019 9078295.40449812,2380538.16717147 9079558.84194849,2381055.03469917 9081757.55388556,2380267.42703791 9082643.61171947,2380710.45634737 9083168.68945391,2379931.06406453 9083021.01509475,2379233.7142464 9083759.36841078,2378442.67794482 9082959.88657981,2378604.00215088 9083424.05072713,2377563.78830111 9083562.16830069,2377341.87289622 9083907.25370813,2377807.53345815 9084052.13288586,2376895.52626593 9084309.0425308,2376862.720412 9084932.57788238,2377600.28996214 9085547.16258457,2376452.50808842 9085383.80323754,2376772.47370081 9086351.87675873,2377839.0034782 9086934.37453989,2379594.6899592 9089526.88193449,2380136.17022631 9089494.07408576,2379758.77488863 9090478.570831,2380341.26525615 9089937.0906658,2380251.02967691 9090511.38319048,2379397.79917583 9090659.06515612,2379307.55246464 9091061.06154116,2380316.65251674 9092365.52577592,2381383.19342608 9091717.39068873,2381227.31274312 9092652.66570207,2381670.34205258 9093128.5061353,2382991.20347059 9091815.82075834,2381965.6837936 9091020.04296678,2382195.4026948 9090019.11564374,2380972.99223445 9088796.72250146,2381941.08218614 9089764.79230159,2382720.17390635 9089461.95191981)))', 3857) AS geom 43 | 44 | ) SELECT ST_IsValid(sample.geom), ST_IsValid(ST_Transform(sample.geom, 4326)) FROM sample 45 | ``` 46 | 47 | ### Find geometry with invalid geodetic coordinates 48 | 49 | 50 | **Example** 51 | ```sql 52 | SELECT ST_Transform(ST_SetSRID('POINT(575 90)'::geometry,4269),102008); 53 | 54 | ERROR: transform: latitude or longitude exceeded limits (-14) 55 | ``` 56 | 57 | **Find geodetic data with invalid coordinates** 58 | ```sql 59 | SELECT * FROM data_tbl 60 | WHERE abs(ST_XMax(geom)) > 180 61 | OR abs(ST_YMax(geom) > 90; 62 | ``` 63 | 64 | -------------------------------------------------------------------------------- /pgp-updel.md: -------------------------------------------------------------------------------- 1 | ## Update, Delete 2 | {: .no_toc } 3 | 4 | 1. TOC 5 | {:toc} 6 | 7 | ## Update 8 | ### Update a column by a spatial condition 9 | 10 | ```sql 11 | UPDATE table1 12 | SET column3 = ( 13 | SELECT 14 | CASE 15 | WHEN table2.column7 >15 THEN 1 16 | ELSE 0 17 | END 18 | FROM table2 19 | WHERE ST_INTERSECTS(table1.geom, table2.geom) 20 | --LIMIT 1 21 | ); 22 | ``` 23 | Is LIMIT 1 needed? 24 | 25 | ## Delete 26 | 27 | ### Delete Geometries Contained in Polygons 28 | 29 | 30 | Use an `EXISTS` expression. 31 | `EXISTS` terminates the subquery as soon as a single row satisfying the `ST_Within` condition is found. 32 | This is an efficient way when traversing a table by row (as in an `UPDATE`/`DELETE`), 33 | or otherwise comparing against a pre-selection (e.g. of ids). 34 | 35 | ```sql 36 | DELETE FROM AS g 37 | WHERE EXISTS ( 38 | SELECT 1 39 | FROM AS p 40 | WHERE ST_Within(g.geom, p.geom) 41 | ); 42 | ``` 43 | 44 | ### Delete Geometries NOT Contained in Polygons 45 | 46 | 47 | Use an `NOT EXISTS` expression. 48 | `NOT EXISTS` terminates the subquery as soon as a single row satisfying the `ST_Within` condition is found. 49 | This is an efficient way when traversing a table by row (as in an `UPDATE`/`DELETE`), 50 | or otherwise comparing against a pre-selection (e.g. of ids). 51 | 52 | ```sql 53 | DELETE FROM AS g 54 | WHERE NOT EXISTS ( 55 | SELECT 1 56 | FROM AS p 57 | WHERE ST_Within(g.geom, p.geom) 58 | ); 59 | ``` 60 | 61 | ### Delete Polygons intersecting Polygons in other tables 62 | 63 | 64 | Use `EXISTS` subqueries. 65 | 66 | ```sql 67 | DELETE FROM a 68 | WHERE EXISTS ( SELECT 1 69 | FROM b 70 | WHERE ST_Intersects(a.geom, b.geom) ) 71 | OR EXISTS ( SELECT 1 72 | FROM c 73 | WHERE ST_Intersects(a.geom, c.geom) ) 74 | OR EXISTS ( SELECT 1 75 | FROM d 76 | WHERE ST_Intersects(a.geom, d.geom) ); 77 | ``` 78 | 79 | ### Delete features which have duplicates within distance 80 | 81 | 82 | Features are duplicate if they have the same `value` column. 83 | 84 | ```sql 85 | DELETE FROM features f 86 | WHERE EXISTS ( 87 | SELECT 1 88 | FROM features 89 | WHERE f.val = val AND f.id <> id AND ST_DWithin(f.geom, geom, ) 90 | ); 91 | ``` 92 | -------------------------------------------------------------------------------- /process/buffer.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Buffers 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ### Variable Width Buffer 12 | 13 | 14 | ![](https://i.stack.imgur.com/sUKMj.png) 15 | 16 | ### Expand a rectangular polygon 17 | 18 | 19 | Use `join=mitre mitre_limit=` 20 | 21 | ```sql 22 | SELECT ST_Buffer( 23 | 'LINESTRING(5 5,15 15,15 5)' 24 | ), 1, 'endcap=square join=mitre mitre_limit=1'); 25 | ``` 26 | 27 | ### Buffer Coastlines with inlet skeletons 28 | 29 | 30 | ### Remove Line Buffer artifacts 31 | 32 | 33 | Quite bizarre, but apparently works. 34 | -------------------------------------------------------------------------------- /process/conflation.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Conflation / Matching 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | 12 | ### Adjust polygons to fill a containing Polygon 13 | 14 | 15 | ### Match Polygons by Shape Similarity 16 | https://gis.stackexchange.com/questions/362560/measuring-the-similarity-of-two-polygons-in-postgis 17 | 18 | There are different ways to measure the similarity between two polygons such as average distance between the boundaries, Hausdorff distance, Turning Function, Comparing Fourier Transformation of the two polygons 19 | 20 | Gives code for Average Boundary Distance 21 | 22 | ### Find Polygon with more accurate linework 23 | https://gis.stackexchange.com/questions/257052/given-two-polygons-find-the-the-one-with-more-detailed-accurate-shoreline 24 | 25 | ### Match sets of LineStrings 26 | https://gis.stackexchange.com/questions/347787/compare-two-set-of-linestrings 27 | 28 | ### Match paths to road network 29 | https://gis.stackexchange.com/questions/349001/aligning-line-with-closest-line-segment-in-postgis 30 | 31 | ### Match paths 32 | https://gis.stackexchange.com/questions/368146/matching-segments-within-tracks-in-postgis 33 | 34 | ### Polygon Averaging 35 | https://info.crunchydata.com/blog/polygon-averaging-in-postgis 36 | 37 | Solution: Overlay, count “depth” of each resultant, union resultants of desired depth. 38 | -------------------------------------------------------------------------------- /process/construct.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Constructions 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Geometric Shapes 12 | 13 | ### Construct regular N-gons 14 | 15 | 16 | **Solution 1: SQL** 17 | 18 | Construct a pentagon (5 sides) of radius 2 centred at (10,10). Those values can be changed to whatever is needed. 19 | 20 | ```sql 21 | SELECT ST_MakePolygon( ST_MakeLine( ARRAY_AGG( 22 | ST_Point( 10 + 2 * COSD(90 + i * 360 / 5 ), 23 | 10 + 2 * SIND(90 + i * 360 / 5 ) )))) 24 | FROM generate_series(0, 5) AS s(i); 25 | ``` 26 | 27 | **Solution 2 - Function `ST_MakeNGon`** 28 | 29 | 30 | ```sql 31 | /* 32 | * @in_params 33 | * center - center POINT geometry 34 | * radius - circumradius [in CRS units] (cirlce that inscribes the *gon) 35 | * sides - desired side count (e.g. 6 for Hexagon) 36 | * rot - rotation offset, clockwise [in degree]; DEFAULT 0.0 (corresponds to planar NORTH) 37 | * 38 | * @out_params 39 | * ngon - resulting N-gon POLYGON geometry 40 | * 41 | * 42 | * The function will create a @sides sided regular, equilateral & equiangular Polygon 43 | * from a given @center and @radius and optional @rot rotation from NORTH 44 | */ 45 | 46 | CREATE OR REPLACE FUNCTION ST_MakeNGon( 47 | IN center GEOMETRY(POINT), 48 | IN radius FLOAT8, 49 | IN sides INT, 50 | IN rot FLOAT8 DEFAULT 0.0, 51 | OUT ngon GEOMETRY(POLYGON) 52 | ) LANGUAGE 'plpgsql' IMMUTABLE STRICT PARALLEL SAFE AS 53 | $$ 54 | DECLARE 55 | _x FLOAT8 := ST_X($1); 56 | _y FLOAT8 := ST_Y($1); 57 | 58 | _cr FLOAT8 := 360.0/$3; 59 | 60 | __v GEOMETRY(POINT)[]; 61 | 62 | BEGIN 63 | FOR i IN 0..$3 LOOP 64 | __v[i] := ST_MakePoint(_x + $2*SIND(i*_cr + $4), _y + $2*COSD(i*_cr + $4)); 65 | END LOOP; 66 | 67 | ngon := ST_MakePolygon(ST_MakeLine(__v)); 68 | END; 69 | $$ 70 | ; 71 | ``` 72 | 73 | ### Construct an envelope for a Geometry at an Angle 74 | 75 | 76 | **Solution** 77 | * Rotate the geometry CW to the desired angle 78 | * Compute the envelope 79 | * Rotate the envelope CCW by the desired angle 80 | 81 | ```sql 82 | WITH data(angle, geom) AS (VALUES 83 | (0.2, 'POLYGON ((10 60, 10 20, 50 30, 70 10, 90 60, 60 80, 40 60, 30 90, 10 60))'::geometry) 84 | ) 85 | SELECT ST_Rotate( ST_Envelope( 86 | ST_Rotate(geom, -angle, ST_Centroid(geom))), 87 | angle, ST_Centroid(geom)) AS envRot 88 | FROM data; 89 | ``` 90 | 91 | ## Geodetic Shapes 92 | 93 | ### Construct ellipses in WGS84 94 | 95 | 96 | 97 | 98 | ## 3D Shapes 99 | 100 | ### 3D Centroid 101 | 102 | 103 | ``` 104 | WITH pts AS 105 | (SELECT 106 | geom( 107 | ST_DumpPoints( 108 | ST_RemovePoint( 109 | ST_ExteriorRing( 110 | ST_GeomFromText('POLYGON Z ((0 0 0, 1 0 0, 1 0 1, 1 1 1, 0 1 1, 0 0 1, 0 0 0 ))') 111 | ), 0 -- remove first point because, for a polygon, first point = last point by definition 112 | ) 113 | ) 114 | ) 115 | ) 116 | SELECT 117 | ST_AsText( 118 | ST_MakePoint( 119 | AVG(ST_X(geom)), 120 | AVG(ST_Y(geom)), 121 | AVG(ST_Z(geom)) 122 | ) 123 | ) geom 124 | FROM pts; 125 | ``` 126 | 127 | ## Lines 128 | 129 | ### Construct a line with given Length and Angle 130 | 131 | 132 | **Solution 1** 133 | ```sql 134 | WITH params AS (SELECT ST_Point(10, 10) AS origin, 10.0 AS length, 60 AS angle) 135 | SELECT ST_Translate( ST_Rotate(ST_MakeLine(ST_Point( -length/2, 0), 136 | ST_Point( length/2, 0)), 137 | radians(angle)), 138 | ST_X(origin), ST_Y(origin), ST_SRID(origin)) AS line 139 | FROM params; 140 | ``` 141 | **Solution 2** 142 | ```sql 143 | WITH params AS (SELECT ST_Point(10, 10) AS origin, 10.0 AS length, 60 AS angle) 144 | SELECT ST_SetSRID(ST_MakeLine( ST_Point( ST_X(origin) - length/2 * cos(radians(angle)), 145 | ST_Y(origin) - length/2 * sin(radians(angle)) ), 146 | ST_Point( ST_X(origin) + length/2 * cos(radians(angle)), 147 | ST_Y(origin) + length/2 * sin(radians(angle)) )), 148 | ST_SRID(origin)) AS line 149 | FROM params; 150 | ``` 151 | 152 | ### Construct Transects (Hatching) along a Line 153 | 154 | 155 | ![](https://i.stack.imgur.com/G9Ypg.png) 156 | 157 | ```sql 158 | CREATE OR REPLACE FUNCTION ST_LineTransects( 159 | lineGeom geometry, 160 | secLen float, 161 | transectLen float) 162 | RETURNS geometry 163 | LANGUAGE sql AS 164 | $BODY$ 165 | WITH 166 | sections AS (SELECT ST_LineSubstring(lineGeom, secStart, CASE WHEN secEnd > 1 THEN 1 ELSE secEnd END) geom 167 | FROM (SELECT lineGeom, ST_Length(lineGeom) AS lineLen) AS t 168 | CROSS JOIN LATERAL 169 | (SELECT i * secLen/lineLen AS secStart, (i+1) * secLen/lineLen AS secEnd 170 | FROM generate_series(0, floor(lineLen / secLen)::integer) AS t(i) 171 | WHERE (secLen * i)/lineLen <> 1.0) AS t2 ), 172 | sectAnglePt AS (SELECT pi() - ST_Azimuth(ST_StartPoint(geom), ST_EndPoint(geom)) AS ang, 173 | ST_LineInterpolatePoint(geom, 0.5) AS centre 174 | FROM sections) 175 | SELECT ST_Collect(ST_MakeLine( 176 | ST_Point( ST_X(centre) - transectLen/2 * cos(ang), 177 | ST_Y(centre) - transectLen/2 * sin(ang)), 178 | ST_Point( ST_X(centre) + transectLen/2 * cos(ang), 179 | ST_Y(centre) + transectLen/2 * sin(ang)) )) AS geom 180 | FROM sectAnglePt; 181 | $BODY$; 182 | ``` 183 | 184 | **Example:** 185 | ```sql 186 | SELECT ST_LineTransects('LINESTRING (1 1, 3 5, 5 3, 7 4, 7 1)', 0.5, 1.0); 187 | ``` 188 | 189 | ## Extending / Filling Polygons 190 | 191 | ### Construct polygons filling gaps in a coverage 192 | 193 | 194 | ![](https://i.stack.imgur.com/2LbzB.png) 195 | 196 | ```sql 197 | SELECT ST_DIFFERENCE(foo.geom, bar.geom) 198 | FROM (SELECT ST_CONVEXHULL(ST_COLLECT(shape::geometry)) as geom FROM schema.polytable) as foo, 199 | (SELECT ST_BUFFER(ST_UNION(shape),0.5) as geom FROM schema.polytable) as bar 200 | ``` 201 | To scale this up/out, could process batches of polygons using a rectangular grid defined over the data space. The constructed gap polygons can be clipped to grid cells. and optional unioned afterwards 202 | 203 | ### Remove Gaps between Polygons 204 | 205 | ![](https://i.stack.imgur.com/XR8lU.png) 206 | 207 | Also: 208 | 209 | **Suggestions** 210 | 211 | * Buffer positively and negatively (see `ST_BufferedUnion`in [PostGIS Addons](https://github.com/pedrogit/postgisaddons/blob/master/postgis_addons.sql) ) 212 | * [Answer](https://gis.stackexchange.com/a/316124/14766) using `ST_Buffer(geom, dist, 'join=mitre mitre_limit=5.0')` with pos/neg distance 213 | 214 | ### Construct polygon joining two polygons 215 | 216 | 217 | ![](https://i.stack.imgur.com/a7idE.png) 218 | 219 | **See Also** 220 | 221 | 222 | **Solution** 223 | * construct convex hull of both polygons together 224 | * subtract convex hull of each polygon 225 | * union with original polygons 226 | * keep only the polygon shell (remove holes) 227 | 228 | ```sql 229 | WITH data(geom) AS (VALUES 230 | ( 'POLYGON ((100 300, 200 300, 200 200, 100 200, 100 300))'::geometry ) 231 | ,( 'POLYGON ((50 150, 100 150, 100 100, 50 100, 50 150))'::geometry ) 232 | ) 233 | SELECT ST_MakePolygon(ST_ExteriorRing(ST_Union( 234 | ST_Difference( 235 | ST_ConvexHull( ST_Union(geom)), 236 | ST_Union( ST_ConvexHull(geom))), 237 | ST_Collect(geom)))) 238 | FROM data; 239 | ``` 240 | 241 | ### Construct expanded polygons to touches a bounding polygon 242 | 243 | 244 | ![Expanding polygons to touch](https://i.stack.imgur.com/VQgHj.png) 245 | 246 | ```sql 247 | WITH 248 | to_buffer(distance, b.id) AS ( 249 | SELECT 250 | ST_Distance(ST_Exteriorring(a.geom), b.geom), 251 | b.id 252 | FROM 253 | polygons_outer a, polygons_inner b 254 | WHERE ST_Contains(a.geom, b.geom) 255 | UPDATE polygons_inner b 256 | SET geom = ST_Buffer(geom, distance) 257 | FROM to_buffer tb 258 | WHERE b.id = tb.id; 259 | ``` 260 | See also note about using a scaling rather than buffer, to preserve shape of polygon 261 | 262 | ### Extend Polygon to meet Line 263 | 264 | 265 | ![](https://i.stack.imgur.com/DQw7k.png) 266 | 267 | **Solution Outline** 268 | 269 | * For each vertex in the polygon shell, use `ST_LineLocatePoint` to find its fractional index along the line. 270 | * Construct the line segments from each vertex to the line, and pick the shortest ones with max and min index 271 | * Construct the subline along the baseline between the max and min indices 272 | * Extract all the line segments from the polygon 273 | * Polygonize the extracted and constructed line segments. This should produce two polygons 274 | * Union the polygonization results 275 | 276 | ## Grids 277 | 278 | ### Construct regular point grid inside polygon 279 | 280 | 281 | 282 | ### Construct Land-Constrained Point Grid 283 | 284 | 285 | ```sql 286 | with geoms as ( 287 | select st_setsrid(encode(wkb_geometry, 'hex'), 4326) as g from coastlines 288 | ) 289 | , row as ( 290 | select st_project(st_setSrid(st_point(174.8431, -41.2581), 4326)::geography, s.a * 50000, pi() / 2) as pt 291 | from generate_series(-10, 10, 1) as s(a) 292 | ) 293 | select st_project(pt, s.a * 50000, 0) as projected_pt 294 | from row, generate_series(-10, 10, 1) as s(a) 295 | where st_distance(st_setSrid(st_point(174.8431, -41.2581), 4326)::geography, st_project(pt, s.a * 50000, 0)) < 500000 296 | and exists(select 1 from geoms where st_nPoints(g) > 1000 and st_contains(g, st_project(pt, s.a * 50000, 0)::geometry)) 297 | ``` 298 | 299 | ![](https://korban.net/img/2019-10-16-12-44-48.png) 300 | 301 | ### Construct Square Grid 302 | 303 | 304 | ![](https://i.stack.imgur.com/vQY0Z.png) 305 | 306 | 307 | 308 | 309 | 310 | ### Construct Quadrilateral Grid 311 | Construct a regularly spaced grid in an arbitrary quadrilateral. 312 | 313 | 314 | 315 | ![](https://i.stack.imgur.com/vwqg0.png) 316 | 317 | **Solution** 318 | Use a pseudo-projective transformation of a grid on a unit square to the quadrilateral. 319 | Transformation is a simple non-linear combination of three basis vectors. 320 | Formula and explanation are [here](https://math.stackexchange.com/a/863702). 321 | 322 | ![](https://i.stack.imgur.com/fTMhb.png) 323 | 324 | ```sql 325 | WITH quad AS (SELECT 326 | 5 AS LLx, 5 AS LLy, 327 | 10 AS ULx, 30 AS ULy, 328 | 25 AS URx, 25 AS URy, 329 | 30 AS LRx, 0 AS LRy 330 | ), 331 | vec AS ( 332 | SELECT LLx AS ox, LLy AS oy, 333 | ULx - LLx AS ux, ULy - LLy AS uy, 334 | LRx - LLx AS vx, LRy - LLy As vy, 335 | URx - LLx - ((ULX - LLx) + (LRx - LLx)) AS wx, 336 | URy - LLy - ((ULy - LLy) + (LRy - LLy)) AS wy 337 | FROM quad 338 | ), 339 | grid AS (SELECT x / 10.0 AS x, y / 10.0 AS y 340 | FROM generate_series(0, 10) AS sx(x) 341 | CROSS JOIN generate_series(0, 10) AS sy(y) 342 | ) 343 | SELECT ST_Point(ox + ux * x + vx * y + wx * x * y, 344 | oy + uy * x + vy * y + wy * x * y) AS geom 345 | FROM vec CROSS JOIN grid; 346 | ``` 347 | ## Medial Axis / Skeleton 348 | 349 | ### Construct Average / Centrelines between Lines 350 | 351 | 352 | ![](https://i.stack.imgur.com/QrEL8.png) 353 | 354 | 355 | 356 | 357 | 358 | Idea: triangulate polygon, then connect midpoints of interior lines 359 | 360 | Idea 2: find line segments for nearest points of each line vertex. Order by distance along line (percentage?). Discard any that have a retrograde direction. Join centrepoints of segments. 361 | 362 | 363 | ### Construct Straight Skeleton 364 | 365 | 366 | ## Polygon Diagonal / Radius 367 | 368 | ### Construct lines joining every vertex in a polygon 369 | 370 | 371 | 372 | Better answer: 373 | ```sql 374 | WITH poly(id, geom)AS (VALUES 375 | ( 1, 'POLYGON ((2 7, 5 9, 9 7, 8 3, 5 2, 2 3, 3 5, 2 7))'::geometry ) 376 | ) 377 | ,ring AS (SELECT ST_ExteriorRing(geom) geom FROM poly) 378 | ,pts AS (SELECT i, ST_PointN(geom, i) AS geom 379 | FROM ring 380 | JOIN LATERAL generate_series(2, ST_NumPoints(ring.geom)) AS s(i) ON true) 381 | SELECT ST_MakeLine(p1.geom, p2.geom) AS geom 382 | FROM pts p1, pts p2 383 | WHERE p1.i > p2.i; 384 | ``` 385 | 386 | ### Construct all diagonals in a concave polygon 387 | 388 | 389 | ![](https://i.stack.imgur.com/TsP6P.png) 390 | 391 | **Solution** 392 | 393 | Using only polygon shell: 394 | ```sql 395 | WITH poly AS 396 | (SELECT ST_MakePolygon(ST_ExteriorRing((ST_Dump(geom)).geom)) geom FROM 397 | (SELECT ST_GeomFromText('POLYGON((25.390624999999982 23.62298461759423,18.183593749999982 19.371888927008566,7.812499999999982 17.87273879517762,5.878906249999982 24.90497143578641,9.570312499999982 25.223427998254586,12.734374999999982 25.064303191014304,15.195312499999982 30.048744443788348,22.578124999999982 30.352588399664125,24.687499999999982 25.857838723065772,25.390624999999982 23.62298461759423))') AS geom 398 | ) boo), 399 | poly_ext AS (SELECT ST_ExteriorRing((ST_Dump(geom)).geom) geom FROM poly), 400 | points AS (SELECT (g.gdump).path AS id, (g.gdump).geom AS geom 401 | FROM (SELECT ST_DumpPoints(geom) AS gdump FROM poly_ext) AS g) 402 | SELECT ST_MakeLine(a.geom, b.geom) AS geom FROM points a CROSS JOIN points b 403 | JOIN poly ON ST_Contains(poly.geom, ST_MakeLine(a.geom, b.geom)) WHERE a.id < b.id; 404 | ``` 405 | 406 | ### Construct longest horizontal line within polygon 407 | 408 | 409 | **Algorithm** 410 | * For every Y value: 411 | * Construct horizontal line across bounding box at Y value 412 | * Intersect with polygon 413 | * Keep longest result line 414 | 415 | ### Construct set of parallel lines across Polygon 416 | 417 | 418 | ![](https://i.stack.imgur.com/KxdqN.png) 419 | 420 | ```sql 421 | SELECT ST_Intersection(line, polygon) AS geom FROM 422 | (SELECT polygon, ST_SetSRID( ST_MakeLine (ST_Point(x_min, y_value),ST_Point(x_max, y_value) ), ST_SRID(polygon)) AS line FROM 423 | (SELECT polygon, GENERATE_SERIES( 424 | FLOOR( ST_YMin(polygon))::int, 425 | CEILING(ST_YMax(polygon))::int,200) y_value, 426 | ST_XMin(polygon) x_min, 427 | ST_XMax(polygon) x_max 428 | FROM (SELECT geom AS polygon FROM data) l 429 | ) AS c 430 | ) AS lines; 431 | ``` 432 | 433 | ### Construct closest boundary point to a point in a polygon 434 | 435 | 436 | (Code below shows use of `ST_Buffer` to force the constructed point to lie outside the polygon.) 437 | 438 | ```sql 439 | WITH polygons AS( 440 | SELECT ST_Buffer(ST_GeomFromText('POINT(0 0)', 4326),2) as geom. -- example polygon 441 | ) 442 | SELECT 443 | ST_AsTEXT(ST_ClosestPoint(ST_ExteriorRing(ST_Buffer(polygons.geom,0.0000001)) 444 | ,ST_GeomFromText('POINT(1 0)', 4326))) 445 | FROM polygons; 446 | ``` 447 | 448 | 449 | 450 | 451 | -------------------------------------------------------------------------------- /process/hull.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Hulls and Covering Polygons 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Based on Lines 12 | 13 | ### Construct Bounding box of set of MULTILINESTRINGs 14 | 15 | ```sql 16 | SELECT type, ST_Envelope(ST_Collect(geom)) 17 | FROM line_table AS foo 18 | GROUP BY type; 19 | ``` 20 | 21 | ### Construct polygon containing lines 22 | 23 | 24 | **Solution** 25 | * Use `ST_Extent` aggregate function on input set. 26 | * Use `ST_ConvexHull` on `ST_Collect` aggregate of input set. 27 | 28 | ### Construct lines between all points of a Polygon 29 | 30 | 31 | ##### Solution 32 | Rework given SQL using CROSS JOIN and a self join 33 | 34 | ## Based on Points 35 | 36 | ### Construct Regions from Points 37 | 38 | 39 | ### Construct regions from large sets of points (100K) tagged with region attribute. 40 | 41 | Could use ST_ConcaveHull, but results would overlap 42 | Perhaps ST_Voronoi would be better? How would this work, and what are limits on size of data? 43 | 44 | ### Construct a Star Polygon from a set of Points 45 | 46 | 47 | ![](https://i.stack.imgur.com/vUHcU.png) 48 | 49 | ```sql 50 | WITH pts(pt) AS (VALUES 51 | (st_transform(st_setsrid(st_makepoint(-97.5660461, 30.4894905), 4326),4269) ), 52 | (st_transform(st_setsrid(st_makepoint(-97.5657216, 30.4902173), 4326),4269) ), 53 | (st_transform(st_setsrid(st_makepoint(-97.5608779, 30.4896142), 4326),4269) ), 54 | (st_transform(st_setsrid(st_makepoint(-97.5605001, 30.491422), 4326),4269) ), 55 | (st_transform(st_setsrid(st_makepoint(-97.5588115, 30.4911697), 4326),4269) ), 56 | (st_transform(st_setsrid(st_makepoint(-97.5588262, 30.4910204), 4326),4269) ), 57 | (st_transform(st_setsrid(st_makepoint(-97.5588262, 30.4910204), 4326),4269)), 58 | (st_transform(st_setsrid(st_makepoint(-97.5585742, 30.4909966), 4326),4269)), 59 | (st_transform(st_setsrid(st_makepoint(-97.5578045, 30.4909263), 4326),4269)), 60 | (st_transform(st_setsrid(st_makepoint(-97.5574653, 30.4908877), 4326),4269)), 61 | (st_transform(st_setsrid(st_makepoint(-97.5571534, 30.4908375), 4326),4269)), 62 | (st_transform(st_setsrid(st_makepoint(-97.5560964, 30.4907427), 4326),4269)) 63 | ), 64 | centroid AS (SELECT ST_Centroid( ST_Collect(pt) ) AS centroid FROM pts), 65 | line AS (SELECT ST_MakeLine( pt ORDER BY ST_Azimuth( centroid, pt ) ) AS geom 66 | FROM pts CROSS JOIN centroid), 67 | poly AS (SELECT ST_MakePolygon( ST_AddPoint( geom, ST_StartPoint( geom ))) AS geom 68 | FROM line) 69 | SELECT geom FROM poly; 70 | ``` 71 | ### Construct a Concave Hull of Points as a Buffer of the Minimum Spanning Tree 72 | 73 | ![](https://i.stack.imgur.com/g7rLC.png) 74 | 75 | SQL [code](https://gist.github.com/andrewxhill/13de0618d31893cdc4c5) to construct a Minimum Spanning Tree. 76 | -------------------------------------------------------------------------------- /process/index.md: -------------------------------------------------------------------------------- 1 | --- 2 | has_children: true 3 | --- 4 | 5 | # Processing 6 | -------------------------------------------------------------------------------- /process/point-dist.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Point Distributions 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ### Generate Evenly-Distributed Points in a Polygon 12 | 13 | 14 | 15 | One solution: create a grid of points and then clip to polygon 16 | 17 | See also: 18 | * 19 | * 20 | 21 | ### Construct Well-spaced Random Points in a Polygon 22 | 23 | 24 | Uses clustering on randomly generated points. 25 | Suggestion is to use neg-buffered polygon to ensure distance from polygon boundary 26 | 27 | A nicer solution will be when PostGIS provides a way to generate random points using [Poisson Disk Sampling](https://www.jasondavies.com/poisson-disc/). 28 | 29 | ### Place Maximum Number of Points in a Polygon 30 | 31 | 32 | ### Sample Linear Point Clouds at given density 33 | 34 | -------------------------------------------------------------------------------- /process/polygonize.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Polygonization 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | 12 | ## Polygonize OSM streets 13 | 14 | 15 | ## Polygonize a set of lines 16 | 17 | 18 | ## Polygonize a set of isolines with bounding box 19 | 20 | 21 | ## Find area enclosed by a set of lines 22 | 23 | -------------------------------------------------------------------------------- /process/surface.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Processing 3 | --- 4 | 5 | # Contouring and Surface Interpolation 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Contouring 12 | ### Generate contours from evenly-spaced weighted points 13 | https://gis.stackexchange.com/questions/85968/clustering-points-in-postgresql-to-create-contour-map 14 | NO SOLUTION 15 | 16 | ### Contouring Irregularly spaced points 17 | https://abelvm.github.io/sql/contour/ 18 | 19 | Solution 20 | An impressive PostGIS-only solution using a Delaunay with triangles cut by contour lines. 21 | Uses the so-called Meandering Triangles method for isolines. 22 | 23 | ## Surface Interpolation 24 | 25 | ### IDW Interpolation over a grid of points 26 | 27 | 28 | Use [Inverse-Distance-Weighting](https://en.wikipedia.org/wiki/Inverse_distance_weighting) (IDW) interpolation on a subset of nearby points. 29 | The **power parameter** `POWER` is chosen according to the weighting desired.. 30 | 31 | ```sql 32 | SELECT SUM( z/d ) / SUM( 1/d ) AS z 33 | FROM ( 34 | SELECT smpl.z as z, 35 | ST_Distance(itp.geom, smpl.geom) ^ POWER AS d 36 | FROM AS smpl 37 | ORDER BY 38 | itp.geom <-> smpl.geom 39 | WHERE smpl.Z IS NOT NULL 40 | LIMIT 41 | ) t; 42 | ``` 43 | 44 | ### Compute Z value of a TIN at a Point 45 | 46 | 47 | ![](https://i.stack.imgur.com/DST02.png) 48 | 49 | **Solution** 50 | 51 | * Use `ST_3DIntersection` (code [here](https://gis.stackexchange.com/a/332906/14766) - requires SF_CGAL) 52 | * Use a custom function (code [here](https://gis.stackexchange.com/a/238297/14766)) 53 | 54 | #### PostGIS TO DO - Add ST_3DInterpolate ? 55 | -------------------------------------------------------------------------------- /query/index.md: -------------------------------------------------------------------------------- 1 | --- 2 | has_children: true 3 | --- 4 | 5 | # Querying 6 | -------------------------------------------------------------------------------- /query/query-distance.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Query by Distance 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Nearest queries 12 | 13 | ### Find Polygons within distance of a Line 14 | 15 | 16 | Solution also shows ordering result by distance. 17 | ```sql 18 | SELECT * 19 | FROM line AS l 20 | LEFT JOIN polygons AS p 21 | ON ST_DWithin(l.geom, p.geom, 200) 22 | ORDER BY l.geom <-> p.geom; 23 | ``` 24 | 25 | ### Find Points within a point-specific Distance of a query point 26 | 27 | 28 | Given a table of points with each record having a `radius` column, 29 | find all points whose distance from a provided query point `QUERY_POINT` is less than `radius` plus a provided distance `QUERY_DIST`. 30 | 31 | **Solution:** 32 | Use `ST_Expand` and a functional index. 33 | 34 | ```sql 35 | -- for GEOMETRY; the radius must be in SRS units 36 | CREATE INDEX ON USING GIST ( ST_Expand(location, radius) ); 37 | 38 | -- for GEOGRAPHY; radius is in meters 39 | CREATE INDEX ON
USING GIST ( _ST_Expand(location, radius) ); 40 | 41 | SELECT * 42 | FROM
AS t 43 | WHERE 44 | -- note the ST_Expand expression needs to match that of the index definition EXACTLY 45 | [_]ST_Expand(t.geom, t.radius) && [_]ST_Expand(, ) 46 | AND ST_DWithin( 47 | , 48 | t.geom, 49 | t.radius + 50 | ); 51 | ``` 52 | 53 | ### Find geometries close to centre of an extent 54 | 55 | 56 | 57 | ### Remove Duplicate Points within given Distance 58 | 59 | 60 | 61 | No good solutions provided. 62 | 63 | ### Use DWithin instead of Buffer 64 | 65 | 66 | ### Find nearest point on boundary of a union of polygons 67 | 68 | 69 | ![](https://i.stack.imgur.com/sRdju.jpg) 70 | 71 | ```sql 72 | SELECT ST_ClosestPoint(ST_Boundary(ST_Union(geom)), ) FROM polygons; 73 | ``` 74 | 75 | ### Find points returned by function within elliptical area 76 | 77 | 78 | ### Find Point with highest elevation along a transect through a set of elevation points 79 | 80 | 81 | ```sql 82 | SELECT Max(elevation) 83 | FROM points p 84 | WHERE ST_DWithin(geom, ST_SetSRID( 85 | ST_MakeLine( ST_Point(-71.160281 42.258729), ST_Point(-71.161144 42.25932)) 86 | , 4326) 87 | , 100); 88 | ``` 89 | 90 | ### Find a single point within a given distance of a road 91 | 92 | 93 | ### Find Polygons near Lines but not intersecting them 94 | 95 | 96 | Following query includes polygons multiple times if there are multiple lines within distance. 97 | ```sql 98 | SELECT p.* 99 | FROM polygons p 100 | INNER JOIN lines l ON ST_DWithin(p.geom,l.geom, DISTANCE ) 101 | WHERE NOT EXISTS ( 102 | SELECT 1 103 | FROM lines l2 104 | WHERE ST_Intersects(p.geom, l2.geom) 105 | ); 106 | ``` 107 | 108 | To include polygons once only: 109 | ```sql 110 | SELECT p.* 111 | FROM polygons p 112 | WHERE EXISTS ( 113 | SELECT 1 114 | FROM lines l 115 | WHERE ST_DWithin(p.geom,l.geom, DISTANCE ) 116 | ) 117 | AND NOT EXISTS ( 118 | SELECT 1 119 | FROM lines l2 120 | WHERE ST_Intersects(p.geom, l2.geom) 121 | ); 122 | ``` 123 | ## Not Within Distance queries 124 | 125 | 126 | ### Find points NOT within distance of lines 127 | 128 | 129 | 130 | #### Solution 1: EXCEPT with DWithin (Fastest) 131 | ```sql 132 | SELECT locations.geom FROM locations 133 | EXCEPT 134 | SELECT locations.geom FROM ways 135 | JOIN locations 136 | ON ST_DWithin( ways.linestring, locations.geom, 3) 137 | ``` 138 | #### Solution 2: LEFT JOIN for non-NULL with DWithin 139 | 2x SLOWER than #1 140 | ```sql 141 | SELECT inj.* 142 | FROM injuries inj 143 | LEFT JOIN bike_routes br 144 | ON ST_DWithin(inj.geom, br.geom, 15) 145 | WHERE br.gid IS NULL 146 | ``` 147 | #### Solution 3: NOT EXISTS with DWithin 148 | Same performance as #2 ? 149 | ```sql 150 | SELECT * 151 | FROM injuries AS inj 152 | WHERE NOT EXISTS 153 | (SELECT 1 FROM bike_routes br 154 | WHERE ST_DWithin(br.geom, inj.geom, 15); 155 | ``` 156 | #### Solution 3: Buffer (Slow) 157 | Buffer line, union, then find all point not in buffer polygon 158 | 159 | ### Find locations NOT within a distance of multiple features in other table 160 | 161 | Find locations beyond a given distance from multiple cities. 162 | 163 | ```sql 164 | SELECT * 165 | FROM points AS p 166 | WHERE NOT EXISTS ( 167 | SELECT 1 168 | FROM cities AS c 169 | WHERE ST_DWithin(c.geom, p.geom, ) 170 | AND city IN ('New York', 'Washington') 171 | ); 172 | ``` 173 | 174 | ### Find Points having no other points in table with same value and within distance 175 | 176 | 177 | **Solution** 178 | Use `NOT EXISTS`. 179 | Select features that do not have a duplicate feature within distance: 180 | 181 | ```sql 182 | SELECT * 183 | FROM points AS a 184 | WHERE NOT EXISTS ( 185 | SELECT 1 186 | FROM points 187 | WHERE a.val = val AND a.id <> id AND ST_DWithin(a.geom, geom, ) 188 | ); 189 | ``` 190 | 191 | ## Farthest queries 192 | 193 | ### Find furthest pair of locations in groups 194 | 195 | 196 | Given a set of locations in multiple groups (e.g. postcodes in districts), 197 | find the pair of locations furthest apart in each group. 198 | 199 | Finding the furthest pair of locations requires testing each pair of locations 200 | and selecting the furthest apart. This can be slightly optimized by using a "triangle join", 201 | which evaluates half the total number of pairs by evaluating only pairs where the first item is less than the second item 202 | (assuming the items have an ordered id). 203 | 204 | Evaluating this over groups requires using one of the standard SQL patterns to select the first row in a group. 205 | (See ). 206 | 207 | **Solution 1: DISTINCT ON** 208 | ```sql 209 | WITH pairs AS ( 210 | SELECT 211 | loc.district, 212 | loc.postcode AS postcode1, 213 | loc2.postcode AS postcode2, 214 | ST_DistanceSphere( ST_Point( loc.lat, loc.long), 215 | ST_Point( loc2.lat,loc2.long) ) AS distance 216 | FROM locations loc 217 | LEFT JOIN locations loc2 218 | ON loc.district = loc2.district 219 | AND loc.postcode < loc2.postcode 220 | -- triangle join compares each pair only once 221 | ) 222 | SELECT DISTINCT ON (p.district) 223 | p.district, 224 | p.postcode1, 225 | p.postcode2, 226 | p.distance 227 | FROM pairs p 228 | ORDER BY p.district, p.distance DESC; 229 | ``` 230 | 231 | **Solution 2: ROW_NUMBER** 232 | ```sql 233 | SELECT * 234 | FROM ( SELECT t1.district, t1.postcode AS postcode1, t2.postcode AS postcode2, 235 | , row_number() OVER( PARTITION BY t1.district 236 | ORDER BY ST_DistanceSphere(ST_Point(t1.lat, t1.long), ST_Point(t2.lat, t2.long)) desc) rn 237 | FROM locations t1 238 | JOIN locations t2 ON t1.district = t2.district AND t1.postcode > t2.postcode 239 | ) t 240 | WHERE rn = 1; 241 | ``` 242 | 243 | **Solution 3: LATERAL** 244 | 245 | TBD 246 | 247 | ### Find Farthest Point from a Polygon 248 | 249 | 250 | ```sql 251 | SELECT ST_Distance((st_dumppoints(pts_geom), 252 | poly.geom) dist 253 | ) ORDR BY dist desc LIMIT 1 254 | ``` 255 | 256 | ### Find farthest vertex from polygon centroid 257 | 258 | ### Find random sample of Point features at least distance D apart 259 | 260 | * Randomize row order 261 | * Loop over rows 262 | * build a MultiPoint union of the result 263 | * add result records if they have distance > D to current result MultiPoint 264 | * terminate when N records have been found, or when no further points can be added 265 | 266 | This is fairly reasonable in performance. For a 2M point table finding 100 different points takes ~ 6 secs. 267 | 268 | ```sql 269 | WITH RECURSIVE rand AS ( 270 | SELECT geom, name FROM geonames ORDER BY random() 271 | ), 272 | pick(count, geomAll, geom, name) AS ( 273 | SELECT 1, geom::geometry AS geomAll, geom::geometry, name 274 | FROM (SELECT geom, name FROM rand LIMIT 1) t 275 | UNION ALL 276 | SELECT count, ST_Union(geomAll, geom), geom, name 277 | FROM (SELECT count + 1 AS count, p.geomAll AS geomAll, r.geom, r.name 278 | FROM pick p CROSS JOIN rand r 279 | WHERE ST_Distance(p.geomAll, r.geom) > 1 -- PARAMETER: Distance 280 | LIMIT 1) t 281 | WHERE count <= 100. -- PARAMETER: Result count 282 | ) 283 | SELECT count, geom, name FROM pick; 284 | -- Use this to visualize result 285 | --SELECT count, ST_AsText(geomAll), ST_AsText(geom), name FROM pick; 286 | ``` 287 | 288 | **Self-contained example:** 289 | 290 | ```sql 291 | WITH RECURSIVE rand AS ( 292 | SELECT geom, 'row' || path[1] AS name 293 | FROM ST_Dump( ST_GeneratePoints(ST_MakeEnvelope(0, 0, 100, 100), 10000)) 294 | ), 295 | pick(count, geomAll, geom, name) AS ( 296 | SELECT 1, geom::geometry AS geomAll, geom::geometry, name 297 | FROM (SELECT geom, name FROM rand LIMIT 1) t 298 | UNION ALL 299 | SELECT count, ST_Union(geomAll, geom), geom, name 300 | FROM (SELECT count + 1 AS count, p.geomAll AS geomAll, r.geom, r.name 301 | FROM pick p CROSS JOIN rand r 302 | WHERE ST_Distance(p.geomAll, r.geom) > 5 303 | LIMIT 1) t 304 | WHERE count <= 100 305 | ) 306 | SELECT count, ST_AsText(geomAll), ST_AsText(geom), name FROM pick; 307 | ``` 308 | 309 | ## Distance Computation 310 | 311 | ### Find Distance and Bearing from Point to Polygon 312 | https://gis.stackexchange.com/questions/27564/how-to-get-distance-bearing-between-a-point-and-the-nearest-part-of-a-polygon 313 | 314 | 315 | -------------------------------------------------------------------------------- /query/query-index.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Using Indexes 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Kinds of Spatial Indexes 12 | 13 | 14 | ![](https://blog.crunchydata.com/hs-fs/hubfs/rtree.png?width=543&name=rtree.png) 15 | 16 | ![](https://blog.crunchydata.com/hs-fs/hubfs/quadtree.png?width=558&name=quadtree.png) 17 | 18 | ## Miscellaneous 19 | 20 | 21 | 22 | 23 | 24 | ## Use ST_Intersects instead of ST_DIsjoint 25 | 26 | 27 | ## Spatial Predicate argument ordering important for indexing 28 | 29 | 30 | This may be due to indexing being used for first ST_Intersects arg, but not second? 31 | 32 | ## Clustering on a spatial Index 33 | 34 | 35 | Advice: clustering likely only improves performance for very large datasets (> 1M rows) 36 | 37 | 38 | 39 | ## Use an Index for performance 40 | 41 | 42 | Just says: Use a spatial index! 43 | -------------------------------------------------------------------------------- /query/query-lines.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Lines 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | 12 | ## Find Lines which have a given angle of incidence 13 | 14 | 15 | #### See Also 16 | 17 | 18 | ## Find lines which are covered by a Line using a tolerance 19 | 20 | 21 | **Solution** 22 | Use `ST_Snap`: 23 | ```sql 24 | WITH lines AS (SELECT (ST_Dump(ST_GeomFromText( 25 | 'GEOMETRYCOLLECTION( 26 | LINESTRING(-76.4631041 38.9533412, -76.45514403057082 38.962161103032216), 27 | LINESTRING(-76.4631041 38.9533412, -76.45349643519081 38.96398666895439), 28 | LINESTRING(-76.45349643519081 38.96398666895439,-76.4525346 38.9650524), 29 | LINESTRING(-76.45514403057082 38.962161103032216,-76.45349643519081 38.96398666895439) 30 | )' 31 | ))).geom AS geom) 32 | SELECT ST_Covers(a.geom, ST_Snap(b.geom, a.geom, 0.01)) 33 | FROM lines a, lines b; 34 | ``` 35 | ## Find Line Intersections at endpoints 36 | 37 | ```sql 38 | SELECT a.id AS aid, b.id AS bid, 39 | ST_Force2D( ST_Intersection(a.geom, b.geom)) AS geom 40 | FROM paths AS a 41 | JOIN paths AS b ON ST_Intersects(a.geom, b.geom) 42 | WHERE a.id < b.id AND ST_Touches(a.geom, b.geom); 43 | ``` 44 | 45 | ## Find Line Intersections NOT at endpoints 46 | 47 | 48 | 49 | **Solution** 50 | Query lines which intersect but which do **not** just touch (at endpoints). 51 | 52 | ```sql 53 | SELECT a.id AS aid, b.id AS bid, 54 | ST_Force2D( ST_Intersection(a.geom, b.geom)) AS geom 55 | FROM paths AS a 56 | JOIN paths AS b ON ST_Intersects(a.geom, b.geom) 57 | WHERE a.id < b.id AND NOT ST_Touches(a.geom, b.geom); 58 | ``` 59 | ## Count number of intersections between Line Segments 60 | 61 | 62 | ## Find Lines which intersect N Polygons 63 | 64 | 65 | #### Solution 66 | Nice application of counting using `HAVING` clause. 67 | 68 | ```sql 69 | SELECT lines.id, lines.geom 70 | FROM lines 71 | JOIN polygons ON st_intersects(lines.geom,polygons.geom) 72 | WHERE polygons.id in (1,2) 73 | GROUP BY lines.id, lines.geom 74 | HAVING count(*) = 2; 75 | ``` 76 | 77 | ## Find Begin and End of circular sublines 78 | 79 | 80 | ## Find Lines that form Rings 81 | 82 | Solutions 83 | Polygonize all lines, then identify lines which intersect each polygon 84 | Complicated recursive solution using ST_LineMerge! 85 | 86 | ## Find Longest Line Segment 87 | 88 | 89 | ## Find non-monotonic Z ordinates in a LineString 90 | 91 | 92 | Assuming the LineStrings are digitized in the correct order (start point is most elevated), 93 | this returns all vertices geom, their respective line , and their position in the vertices array of that line, 94 | for all vertices with higher Z value as their predecessor. 95 | 96 | ```sql 97 | SELECT ln_id, vtx_id, geom 98 | FROM (SELECT ln. AS ln_id, 99 | dmp.path[1] AS vtx_id, 100 | dmp.geom, 101 | ST_Z(dmp.geom) < LAG(ST_Z(dmp.geom)) OVER(PARTITION BY ln. ORDER BY dmp.path[1]) AS is_valid 102 | FROM AS ln, 103 | LATERAL ST_DumpPoints(ln.geom) AS dmp 104 | ) q 105 | WHERE NOT is_valid; 106 | ``` 107 | 108 | ## Query LineString Vertices by Measures 109 | 110 | 111 | Given a Linestring wit timestamps as measure value, find segments where duration between start and end timestamps is larger than X minutes. 112 | 113 | **Solution** 114 | * extract vertices as geoms with `ST_DumpPoints` 115 | * compute difference between consecutive M values using `LAG` window function 116 | * query for the required difference 117 | 118 | ```sql 119 | SELECT * FROM 120 | (select 121 | ST_M(geom) - LAG( ST_M(geom)) OVER () diff, 122 | path 123 | FROM ST_DumpPoints( 'LINESTRING M (0 0 0, 10 0 20, 12 0 40, 20 0 50, 21 0 70)')) p 124 | WHERE diff > 10; 125 | ``` 126 | 127 | ## Query Invalid Zero-Length LineStrings 128 | 129 | 130 | **Problem:** Zero-length LineStrings are invalid, and hence cause spatial predicates such as `ST_Intersects` to return `false`. 131 | 132 | **Solution** 133 | 134 | The work-around is to run `ST_MakeValid` on the geometry. 135 | 136 | ```sql 137 | SELECT ST_Intersects( 'LINESTRING (544483.525 6849134.28, 544483.525 6849134.28)', 138 | 'POLYGON ((543907.636214323 6848710.84802846, 543909.787417164 6849286.92923919, 544869.040437688 6849283.30837091, 544866.842236582 6848707.22673193, 543907.636214323 6848710.84802846))') AS test1, 139 | ST_Intersects( ST_MakeValid( 'LINESTRING (544483.525 6849134.28, 544483.525 6849134.28)' ), 140 | 'POLYGON ((543907.636214323 6848710.84802846, 543909.787417164 6849286.92923919, 544869.040437688 6849283.30837091, 544866.842236582 6848707.22673193, 543907.636214323 6848710.84802846))') AS test2; 141 | ``` 142 | 143 | 144 | 145 | -------------------------------------------------------------------------------- /query/query-nn.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Nearest-Neighbour 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ### Technical Explanation 12 | 13 | 14 | `<->` Operator [manual](https://postgis.net/docs/geometry_distance_knn.html). 15 | 16 | PostGIS workshop - [Nearest Neighbour Searching](https://postgis.net/workshops/postgis-intro/knn.html). 17 | 18 | ### Using KNN with JOIN LATERAL 19 | 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | ## Point / Point 31 | 32 | ### Find Nearest Point to Points in same table of geodetic points 33 | 34 | 35 | **Solution** 36 | 37 | Note casts to `geography` to compute correct geodetic distance. 38 | 39 | ```sql 40 | SELECT p1.id AS id1, 41 | p2.id AS id2, 42 | ST_Distance(p1.geom::geography, p2.geom::geography) AS dist 43 | FROM points AS p1 44 | CROSS JOIN LATERAL ( 45 | SELECT id, 46 | geom 47 | FROM points 48 | WHERE p1.id <> id 49 | -- AND ST_DWithin(p1.geom::geography, geom::geography, 10000) 50 | ORDER BY p1.geom::geography <-> geom::geography 51 | LIMIT 1 52 | ) AS p2; 53 | ``` 54 | 55 | ### Nearest Point to Points in different table 56 | 57 | 58 | 59 | Very thorough explanation, including difference between geom and geog 60 | ```sql 61 | SELECT g1.gid AS gref_gid, 62 | g2.gid AS gnn_gid, 63 | g2.code_mun, 64 | g1.codigo_mun, 65 | g2.text, 66 | g2.via AS igcvia1 67 | FROM u_nomen_dom As g1 68 | JOIN LATERAL ( 69 | SELECT gid, 70 | code_mun, 71 | text, 72 | via 73 | FROM u_nomen_via AS g 74 | WHERE g1.codigo_mun = g.codigo_mun 75 | ORDER BY g1.geom <-> g.geom 76 | LIMIT 1 77 | ) AS g2 78 | ON true; 79 | ``` 80 | 81 | 82 | 83 | 84 | Lots of obsolete options, dbastons answer is best 85 | 86 | ## Match locations to nearest points in another set 87 | 88 | 89 | **Use Case:** Given a set of collision locations and a set of intersections, match collisions to the nearest intersection. 90 | 91 | **Solution** 92 | 93 | This is efficiently computed using a KNN query, iterating over each collision to find the nearest intersection. 94 | 95 | ```sql 96 | SELECT c.*, i.id, i.geom 97 | FROM collisions c 98 | CROSS JOIN LATERAL 99 | (SELECT id, geom 100 | FROM intersections 101 | ORDER BY c.geom <-> geom 102 | LIMIT 1) i; 103 | ``` 104 | 105 | ### Compute point value as average of N nearest points 106 | 107 | 108 | #### Solution 109 | Use `JOIN LATERAL` and KNN `<->`: 110 | ```sql 111 | SELECT a.id, a.geom, AVG(c.temp_val) temp_val 112 | FROM tablea a 113 | CROSS JOIN LATERAL 114 | (SELECT temp_val 115 | FROM tableb b 116 | ORDER BY b.geom <-> a.geom 117 | LIMIT 4) AS c 118 | GROUP BY id, geom 119 | ``` 120 | 121 | ### Find Nearest Neighbours having record in temporal join table 122 | 123 | 124 | ## Point / Line 125 | 126 | ### Find Shortest Line from Points to Roads (KNN, LATERAL) 127 | 128 | 129 | 130 | 131 | 132 | 133 | ### Snap Points to Nearest Point on Line 134 | 135 | 136 | 137 | ```sql 138 | UPDATE points 139 | SET geom = ( 140 | SELECT ST_ClosestPoint(lines.geom, points.geom) 141 | FROM lines 142 | WHERE ST_DWithin(points.geom, lines.geom, 5) 143 | ORDER BY lines.geom <-> points.geom 144 | LIMIT 1 145 | ); 146 | ``` 147 | 148 | -------------------------------------------------------------------------------- /query/query-pip.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Point-In-Polygon 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Find Points contained in Polygons, keeping attributes 12 | 13 | 14 | 15 | **Solution** 16 | A simple query to do this is: 17 | ```sql 18 | SELECT pt.id, poly.* 19 | FROM points pt 20 | JOIN polygons poly ON ST_Intersects(poly.geom, pt.geom); 21 | ``` 22 | Caveat: this will return multiple records if a point lies in multiple polygons. 23 | 24 | For efficiency, or because the polygons are known to be overlapping, it is useful to ensure only a single record is returned per point. 25 | Use `JOIN LATERAL` and `LIMIT 1` to do this: 26 | ```sql 27 | SELECT pt.id, poly.* 28 | FROM points pt 29 | LEFT OUTER JOIN LATERAL 30 | (SELECT * FROM polygons poly 31 | WHERE ST_Intersects(poly.geom, pt.geom) LIMIT 1) AS poly ON true; 32 | ``` 33 | To omit points not in any polygon, use `INNER JOIN` (or just `JOIN`) instead of `LEFT OUTER JOIN`. 34 | 35 | ## Count kinds of Points in Polygons 36 | 37 | ```sql 38 | SELECT 39 | polyname, 40 | COUNT(pid) FILTER (WHERE pid='w') AS w, 41 | COUNT(pid) FILTER (WHERE pid='x') AS x, 42 | COUNT(pid) FILTER (WHERE pid='y') AS y, 43 | COUNT(pid) FILTER (WHERE pid='z') AS z 44 | FROM polygons 45 | LEFT JOIN points ON st_intersects(points.geom, polygons.geom) 46 | GROUP BY polyname; 47 | ``` 48 | ## Optimize Point-in-Polygon query by evaluating against smaller polygons 49 | Count lightning occurences inside countries 50 | 51 | 52 | 53 | ## Optimize Point-in-Polygon query by gridding polygons 54 | Count occurences inside river polygons 55 | 56 | 57 | 58 | ## Find smallest Polygon containing Point 59 | 60 | 61 | ![](https://i.stack.imgur.com/vFDCs.png) 62 | 63 | #### Solution 64 | Choose containing polygon with smallest area 65 | ```sql 66 | SELECT DISTINCT ON (compequip.id), compequip.*, a.* 67 | FROM compequip 68 | LEFT JOIN a 69 | ON ST_within(compequip.geom, a.geom) 70 | ORDER BY compequip.id, ST_Area(a.geom) 71 | ``` 72 | ## Find Points NOT in Polygons 73 | 74 | 75 | 76 | 77 | 78 | 79 | This is not PiP, but the solution of using NOT EXISTS might be applicable? 80 | 81 | 82 | 83 | ## Find Point in Polygon with greatest attribute 84 | Given 2 tables: 85 | 86 | * `obstacles` - Point layer with a column `height_m INTEGER` 87 | * `polyobstacles` - Polygon layer 88 | 89 | Select the highest obstacle in each polygon. If there are several points with the same highest height a random one of those is selected. 90 | 91 | #### Solution - JOIN LATERAL 92 | ```sql 93 | SELECT poly.id, obs_max.* 94 | FROM polyobstacle poly 95 | JOIN LATERAL (SELECT * FROM obstacles o 96 | WHERE ST_Contains(poly.geom, o.geom) 97 | ORDER BY height_m LIMIT 1 98 | ) AS obs_max ON true; 99 | ``` 100 | #### Solution - DISTINCT ON 101 | Do a spatial join between polygon and points and use `SELECT DISTINCT ON (poly.id) poly.id, o.height...` 102 | 103 | #### Solution - ARRAY_AGG 104 | ```sql 105 | SELECT p.id, (array_agg(o.id order by height_m))[1] AS highest_id 106 | FROM polyobstacles p JOIN obstacles o ON ST_Contains(p.geom, o.geom) 107 | GROUP BY p.id; 108 | ``` 109 | ## Find Polygon containing Point 110 | Basic query - with tables of address points and US census blocks, find state for each point 111 | Discusses required indexes, and external parallelization 112 | 113 | 114 | ## Count Points in Polygons with two Point tables 115 | 116 | 117 | ```sql 118 | SELECT ply.polyname, SUM(pnt1.cnt) AS pointtable1count, SUM(pnt2.cnt) AS pointtable2count 119 | FROM polytable AS ply, 120 | LATERAL ( 121 | SELECT COUNT(pt.*) AS cnt 122 | FROM pointtable1 AS pt 123 | WHERE ST_Intersects(ply.geom, pt.geom) 124 | ) AS pnt1, 125 | LATERAL ( 126 | SELECT COUNT(pt.*) AS cnt 127 | FROM pointtable2 AS pt 128 | WHERE ST_Intersects(ply.geom, pt.geom) 129 | ) AS pnt2 130 | GROUP BY 1; 131 | ``` 132 | -------------------------------------------------------------------------------- /query/query-shape-valid.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Shape, Validity, Duplicates 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | # Geometric Shape 12 | 13 | ## Find narrow Polygons 14 | 15 | 16 | ![](https://i.stack.imgur.com/3ATxf.png) 17 | 18 | #### Solution 1 - Radius of Maximum Inscribed Circle 19 | Use function [`ST_MaximumInscribedCircle`](https://postgis.net/docs/manual-dev/ST_MaximumInscribedCircle.html) 20 | to compute the radius of the Maximum Inscribed Circle of each polygon, and then select using desired cut-off. 21 | This is much faster than computing negative buffers. 22 | 23 | #### Solution 2 - Negative Buffer 24 | Detect thin polygons using a test: `ST_Area(ST_Buffer(geom, -10)) = 0`. 25 | This is not very performant. 26 | 27 | #### Solution 3 - Thinness Ratio 28 | Use the Thinness Ratio: `TR(Area,Perimeter) = Area * 4 * pi / (Perimter^2)`. 29 | 30 | This is only a heuristic approximation, and it's hard to choose appropriate cut-off for the value of the ratio. 31 | 32 | See 33 | 34 | ## Find rectangular Polygons 35 | 36 | 37 | #### Solution 1 - Quadrilaterals 38 | 39 | If rectangles are required to have exactly 4 corners, then only polygons where ST_NPoints(geom) > 5 need to be considered. 40 | 41 | To test quadrilaterals for rectangularity, compare the lengths of their diagonals. In a rectangle the diagonal lengths are (almost) equal. Since finite numerical precision means the lengths will rarely be exactly equal, a tolerance factor is needed To use a dimension-free tolerance the lengths can be normalized by the total length to give the **rectangularity ratio**. 42 | 43 | A query computing the rectangularity ratio from a dataset of 2 slightly skewed rectangles and a perfect rectangle: 44 | 45 | ```sql 46 | WITH data(id, geom) AS (VALUES 47 | (1, 'POLYGON((144.78116 -37.824855, 144.780843 -37.826916, 144.782018 -37.827019, 144.78232 -37.82496, 144.78116 -37.824855))') 48 | ,(3, 'POLYGON((153.193238 -27.682795, 153.19302 -27.68375, 153.193568 -27.683843, 153.193795 -27.682894,153.193238 -27.682795))') 49 | ,(4, 'POLYGON ((153.1931 -27.6828, 153.1937 -27.6828, 153.19370000000004 -27.6838, 153.1931 -27.6838, 153.1931 -27.6828))') 50 | ) 51 | SELECT id, 52 | (ST_Distance( ST_PointN(ST_ExteriorRing(geom), 1), ST_PointN(ST_ExteriorRing(geom), 3)) 53 | - ST_Distance( ST_PointN(ST_ExteriorRing(geom), 2), ST_PointN(ST_ExteriorRing(geom), 4))) 54 | / (ST_Distance( ST_PointN(ST_ExteriorRing(geom), 1), ST_PointN(ST_ExteriorRing(geom), 3)) 55 | + ST_Distance( ST_PointN(ST_ExteriorRing(geom), 2), ST_PointN(ST_ExteriorRing(geom), 4))) AS rect_ratio 56 | FROM data; 57 | ``` 58 | #### Solution 2 - Rectangles with many vertices 59 | 60 | If it is required to test the rectangularity of polygons with more than 4 vertices, then: 61 | 62 | * Compute the Minimum Bounding Rectangle using `ST_OrientedEnvelope` 63 | * Compute the Hausdorff Distance between the MBR and the original polygon using `ST_HausdorffDistance` 64 | * Test if the HD is less than some required value 65 | 66 | # Invalid Geometry 67 | 68 | ## Skip invalid geometries when querying 69 | 70 | 71 | # Duplicate Geometry 72 | 73 | ## Find and Remove duplicate geometry rows 74 | 75 | 76 | * **Input:** table where some rows have duplicate geometry, and no identifying key 77 | * **Ouput:** table with duplicate rows removed 78 | 79 | ```sql 80 | SELECT geom, fld1, fld2 81 | FROM (SELECT row_number() OVER (PARTITION BY geom) AS row_num, 82 | geom, fld1, fld2 83 | FROM some_table) AS t 84 | WHERE row_num = 1; 85 | ``` 86 | 87 | ## Merge tables of grid cell Polygons 88 | 89 | 90 | * **Input:** 10 tables of grid cells, with different attributes. Geometries are the grid cell polygons. 91 | Grids may have different cell sizes, and may be overlapping. 92 | * **Ouput:** Table with all attributes, with records for same cell merged into single record. Missing attributes are null. 93 | 94 | **Solution** 95 | 96 | 1. Extract unique grid cell geometries: 97 | ```sql 98 | CREATE tmp_table AS 99 | SELECT DISTINCT geom FROM 100 | ( 101 | SELECT geom from table1 102 | UNION 103 | SELECT geom from table2 104 | ... 105 | ) 106 | ``` 107 | 108 | 2. Extract attributes via LEFT JOINs against the source tables 109 | ```sql 110 | SELECT a.geom,t1.text1a,t1.text1b,t2.int2a,... 111 | FROM temp_table a 112 | LEFT JOIN table1 t1 ON a.geom = t1.geom 113 | LEFT JOIN table2 t2 ON a.geom = t2.geom 114 | ... 115 | ``` 116 | 117 | ## Find geometries which are NOT in another table 118 | 119 | 120 | Given two tables of polygons which are mostly but not identical, report the records in table 1 which do not exist in table 2. 121 | The only matching criteria is to check geometric equality. 122 | 123 | **Solution** 124 | 125 | Use an **anti-join** with `EXISTS` and a filter using `&&` and `ST_Equals`. 126 | `EXISTS` short-circuits execution when the first row is added to the result set, so this query benefits from early hits. 127 | This matches the assumption of only a small fraction of geometries not matching. 128 | 129 | ```sql 130 | SELECT t1.geom 131 | FROM tbl1 AS t1 132 | WHERE NOT EXISTS ( 133 | SELECT 1 134 | FROM tbl2 AS t2 135 | WHERE t1.geom && t2.geom 136 | AND 137 | ST_Equals(t1.geom, t2.geom) 138 | ); 139 | ``` 140 | 141 | 142 | 143 | 144 | 145 | -------------------------------------------------------------------------------- /query/query-spatial-rel.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Spatial Relationships 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Non-Intersection 12 | 13 | ### Find geometries which do NOT intersect/equal geometries in another set 14 | 15 | 16 | **Solution** 17 | 18 | Do NOT use a `JOIN` with `ST_Disjoint` or `NOT ST_Equals`, since that does not use the spatial index. 19 | 20 | Use an [**anti-join**](https://www.crunchydata.com/blog/rise-of-the-anti-join) 21 | with `NOT EXISTS` or `LEFT JOIN / null` 22 | 23 | * Anti-join with `NOT EXISTS`: 24 | 25 | ```sql 26 | SELECT * FROM polygons 27 | WHERE NOT EXISTS (SELECT 1 FROM streets WHERE ST_Intersects(polygons.geom, streets.geom)) 28 | ``` 29 | 30 | * Anti-join with `LEFT JOIN ON ST_Intersects/ST_Equals` with `WHERE right-side = NULL` 31 | 32 | ### Find geometries which do not intersect other geometries in same set 33 | 34 | 35 | **Solution - Anti-Join** 36 | 37 | Use `NOT EXISTS` against a sub-query testing for intersection with *another* geometry. 38 | Avoid reporting self-intersection by checking if ids are different 39 | 40 | **Solution - `ST_ClusterDBSCAN`** 41 | 42 | Use DBSCAN clustering with tolerance = 0 and a minimum cluster size of 2: 43 | ``` 44 | SELECT id, geom 45 | FROM (SELECT id, geom, 46 | ST_ClusterDBSCAN(geom, eps := 0, minpoints := 2) OVER () AS cluster_id 47 | FROM data) t 48 | WHERE cluster_id IS NULL 49 | ``` 50 | 51 | ## Spatial Relationships with a Tolerance 52 | 53 | ### Geometry Equality with Tolerance 54 | Example: 55 | 56 | This post is about needing `ST_Equals` to have a tolerance to accommodate small differences caused by reprojection 57 | 58 | 59 | This is about small coordinate differences defeating `ST_Equals`, and using `ST_SnapToGrid` to resolve the problem: 60 | 61 | 62 | This says that copying geometries to another database causes them to fail `ST_Equals` (not sure why copy would change the geom - perhaps done using WKT?). Says that using buffer is too slow 63 | 64 | 65 | 66 | 67 | ### Emulating Touches with tolerance 68 | 69 | 70 | 71 | The problem arises when using overlay functions with a distance tolerance (snap-rounding) 72 | with polygons as input. This is done to avoid result artifacts. 73 | Theoretically, if `C = difference(union(A, B), B)` then `touches(A, C) = true` 74 | (i.e. A and C should only intersect in a line.) 75 | This is not necessarily true in practice, due to numerical imprecision. 76 | Using overlay with snap-rounding makes this obvious, but it can happen in any overlay mode. 77 | A tolerance-based approach must be used to determine if A and result C effectively touch 78 | (i.e. intersect "almost" in a line). 79 | 80 | **Solutions** 81 | 82 | * test whether `ST_Intersection(A, B, tol)` is linear 83 | * test whether `ST_Intersection(A, B)` has a small area (based on a fraction of the areas of the input geometries) 84 | * test whether the boundary of A which lies within B lies within 85 | the tolerance distance of the boundary of B. 86 | This is the exact equivalent of "touches with tolerance". 87 | It can be done in two ways: 88 | * `ST_Covers( ST_Buffer(ST_Boundary(B), tol), ST_Intersection(ST_Boundary(A), B) )` 89 | * `ST_OrientedHausdorffDistance(ST_Intersection(ST_Boundary(A), B), ST_Boundary(B)) <= tol` 90 | (**NOTE:** ST_OrientedHausdorffDistance (or equivalent) is not yet available in PostGIS) 91 | 92 | ### Discrepancy between GEOS predicates and PostGIS Intersects 93 | 94 | 95 | Actually it doesn’t look like there is a discrepancy now. But still a case where a distance tolerance might clarify things. 96 | 97 | ### Test if two 3D geometries are equal 98 | 99 | 100 | ### `ST_ClosestPoint` does not intersect Line 101 | 102 | 103 | 104 | **Solution** 105 | 106 | Use `ST_DWithin` 107 | 108 | 109 | ## Polygon / Polygon 110 | 111 | ### Find Polygons not contained by other Polygons 112 | 113 | 114 | ![](https://i.stack.imgur.com/SeTON.png) 115 | 116 | **Solution** 117 | 118 | This relationship can be called `interiorIntersects`. 119 | It can be used to determine if polygons form a valid polygonal coverage. 120 | It can be evaluated as: 121 | ```sql 122 | ST_Relate(a.geom, b.geom, 'T********') 123 | ``` 124 | 125 | See this post for possible robustness issues with this relationship test: 126 | 127 | 128 | ### Find Polygons not contained by other Polygons 129 | 130 | 131 | **Solution** 132 | 133 | Use the LEFT JOIN on `ST_Contains` with NULL result pattern 134 | 135 | ### Find non-covered polygons 136 | 137 | ```sql 138 | WITH 139 | data AS ( 140 | SELECT * FROM (VALUES 141 | ( 'A', 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'::geometry ), 142 | ( 'B', 'POLYGON ((300 200, 400 200, 400 100, 300 100, 300 200))'::geometry ), 143 | ( 'C', 'POLYGON ((100 400, 200 400, 200 300, 100 300, 100 400))'::geometry ), 144 | ( 'AA', 'POLYGON ((120 380, 180 380, 180 320, 120 320, 120 380))'::geometry ), 145 | ( 'BA', 'POLYGON ((110 180, 160 180, 160 130, 110 130, 110 180))'::geometry ), 146 | ( 'BB', 'POLYGON ((170 130, 190 130, 190 110, 170 110, 170 130))'::geometry ), 147 | ( 'CA', 'POLYGON ((330 170, 380 170, 380 120, 330 120, 330 170))'::geometry ), 148 | ( 'AAA', 'POLYGON ((330 170, 380 170, 380 120, 330 120, 330 170))'::geometry ), 149 | ( 'BAA', 'POLYGON ((121 171, 151 171, 151 141, 121 141, 121 171))'::geometry ), 150 | ( 'CAA', 'POLYGON ((341 161, 351 161, 351 141, 341 141, 341 161))'::geometry ), 151 | ( 'CAB', 'POLYGON ((361 151, 371 151, 371 131, 361 131, 361 151))'::geometry ) 152 | ) AS t(id, geom) 153 | ) 154 | SELECT a.id 155 | FROM data AS A 156 | LEFT JOIN data AS b ON a.id <> b.id AND ST_CoveredBy(a.geom, b.geom) 157 | WHERE b.geom IS NULL; 158 | ``` 159 | 160 | ### Find Polygons NOT covered by union of other Polygons 161 | 162 | 163 | ### Find Polygons covered by a set of other polygons 164 | 165 | 166 | **Solution** 167 | 168 | For each polygon, compute union of polygons which intersect it, then test if the union covers the polygon 169 | 170 | ### Improve performance to find Polygons covered by other Polygons 171 | 172 | 173 | `pop` represents populated areas and it contains about 30k of polygons. 174 | `polys` is smaller polygons with about 120M recors. Want to count how many smaller polygons are within populated areas 175 | 176 | Depending on the average shape of those Polygons you may see a boost in performance when pre-filtering by the `ST_Centroid` of the public.polys.wkb_geometry: 177 | The idea is to limit the containment check to only those Polygons where at least the `ST_Centroid` intersects the larger Polygon. 178 | Could use `ST_PointOnSurface` too, but this approach only makes sense where the checked polygon is small enough to pass the bbox containment, but outside the actual bounds. 179 | 180 | ```sql 181 | SELECT COUNT(ply.*) 182 | FROM public.polys AS small 183 | JOIN public.pop_area AS big 184 | ON big.geom ~ small.geom 185 | AND ST_Intersects(big.geom, ST_Centroid( small.geom )) 186 | WHERE ST_Contains(big.geom, small.geom); 187 | ``` 188 | 189 | ### Find Polygons which touch in a line 190 | ```sql 191 | WITH 192 | data(id, geom) AS (VALUES 193 | ( 1, 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'::geometry ), 194 | ( 2, 'POLYGON ((250 150, 200 150, 200 250, 250 250, 250 150))'::geometry ), 195 | ( 3, 'POLYGON ((300 100, 250 100, 250 150, 300 150, 300 100))'::geometry ) 196 | ) 197 | SELECT a.id, b.id, 198 | ST_Relate(a.geom, b.geom), 199 | ST_Relate(a.geom, b.geom, '****1****') AS is_line_touch 200 | FROM data a CROSS JOIN data b WHERE a.id < b.id; 201 | ``` 202 | 203 | ### Find Polygons in a Coverage NOT fully enclosed by other Polygons 204 | 205 | 206 | ![](https://i.stack.imgur.com/tp5WK.png) 207 | 208 | **Solution** 209 | 210 | Find each polygon where the total length of the intersection with adjacent polygons is less than length of its boundary. 211 | 212 | ```sql 213 | SELECT a.id 214 | FROM data a 215 | INNER JOIN data b ON (ST_Intersects(a.geom, b.geom) AND a.id != b.id) 216 | GROUP BY a.id 217 | HAVING 1e-6 > 218 | abs( ST_Length(ST_ExteriorRing(a.geom)) - 219 | SUM( ST_Length(ST_Intersection(ST_ExteriorRing(a.geom), ST_ExteriorRing(b.geom))))); 220 | ``` 221 | 222 | ### Find Polygons with maximum overlap with another Polygon table 223 | 224 | **Solution with `JOIN LATERAL`** 225 | 226 | 227 | 228 | Example: For each mountain area, find country which has largest overlap. 229 | ```sql 230 | SELECT a.id, a.mountain, b.country 231 | FROM mountains a 232 | LEFT JOIN LATERAL 233 | (SELECT country FROM countrytable 234 | WHERE ST_Intersects(countrytable.geom, a.geom) 235 | ORDER BY ST_Area(ST_Intersection(countrytable.geom, a.geom)) DESC NULLS LAST 236 | LIMIT 1 237 | ) b ON true; 238 | ``` 239 | 240 | **Solution using `DISTINCT ON`** 241 | 242 | 243 | 244 | 1) Calculate area of intersection for every pair of rows which intersect. 245 | 2) Order them by a.id and by intersection area when a.id are equal. 246 | 3) For each `a.id` keep the first row (which has the largest intersection area because of ordering in step 2). 247 | 248 | ```sql 249 | SELECT DISTINCT ON (a.id) 250 | a.id AS a_id, 251 | b.id AS b_id, 252 | ST_Area(ST_Intersection( a.geom, b.geom )) AS intersect_area 253 | FROM a, b 254 | WHERE st_intersects( a.geom, b.geom) 255 | ORDER BY a.id, ST_Area(ST_Intersection( a.geom, b.geom )) DESC 256 | ``` 257 | 258 | ### Find Polygons intersecting another Polygon table using ST_Subdivide 259 | 260 | 261 | 262 | Subdividing Polygons into smaller pieces improves the selectivity of indexes, 263 | and improves the performance of `ST_Intersects`. 264 | 265 | ```sql 266 | CREATE TABLE lte_subdivided AS 267 | SELECT ST_Subdivide(geom) as GEOM, gid 268 | FROM lde_coverage; 269 | 270 | CREATE TABLE cities_subdivided AS 271 | SELECT ST_Subdivide(geom) as GEOM, id 272 | FROM cities; 273 | 274 | CREATE INDEX cgx ON cities_subdivided USING GIST (geom); 275 | CREATE INDEX lgx on lte_subdivided USING GIST (geom); 276 | 277 | SELECT distinct c.id 278 | FROM cities_subdivided c 279 | JOIN lte_subdivided l 280 | ON ST_Intersects(c.geom, l.geom) 281 | ``` 282 | 283 | ### Compute hierarchy of a nested Polygonal Coverage 284 | 285 | 286 | Given a table of polygons which form a set of nested/hierarchical coverages, compute an explicit hierachy path for each polygon 287 | 288 | ![](https://i.stack.imgur.com/d8iEG.jpg) 289 | 290 | If the source table is: 291 | ``` 292 | geom of A 293 | geom of AA 294 | geom of AB 295 | geom of AC 296 | geom of AB1 297 | geom of AB2 298 | geom of AC1 299 | geom of AC2 300 | geom of AC11 301 | geom of AC12 302 | geom of AC21 303 | geom of AC22 304 | ``` 305 | the output will be: 306 | ``` 307 | AA, A, geom of AA 308 | AB1, AB, A, geom of AB1 309 | AB2, AB, A, geom of AB2 310 | AC11, AC1, AC, A, geom of AC11 311 | AC12, AC1, AC, A, geom of AC12 312 | AC21, AC2, AC, A, geom of AC21 313 | AC22, AC2, AC, A, geom of AC21 314 | ``` 315 | 316 | **Solution** 317 | 318 | Determine contains relationships based on interior points and areas. Can use a recursive query on that to extract paths if needed. 319 | 320 | ```sql 321 | WITH RECURSIVE data(id, geom) AS (VALUES 322 | ('AC11', 'POLYGON ((100 200, 150 200, 150 150, 100 150, 100 200))'), 323 | ('AC12', 'POLYGON ((200 200, 200 150, 150 150, 150 200, 200 200))'), 324 | ('AC21', 'POLYGON ((200 100, 150 100, 150 150, 200 150, 200 100))'), 325 | ('AC22', 'POLYGON ((100 100, 100 150, 150 150, 150 100, 100 100))'), 326 | ('AC1', 'POLYGON ((200 200, 200 150, 100 150, 100 200, 200 200))'), 327 | ('AC2', 'POLYGON ((200 100, 100 100, 100 150, 200 150, 200 100))'), 328 | ('AC', 'POLYGON ((100 200, 200 200, 200 100, 100 100, 100 200))'), 329 | ('AB1', 'POLYGON ((100 300, 150 300, 150 200, 100 200, 100 300))'), 330 | ('AB2', 'POLYGON ((200 300, 200 200, 150 200, 150 300, 200 300))'), 331 | ('AB', 'POLYGON ((100 300, 200 300, 200 200, 100 200, 100 300))'), 332 | ('AA', 'POLYGON ((0 300, 100 300, 100 100, 0 100, 0 300))'), 333 | ('A', 'POLYGON ((200 100, 0 100, 0 300, 200 300, 200 100))') 334 | ), 335 | -- compute all containment links 336 | contains AS ( SELECT p.id idpar, c.id idch, ST_Area(p.geom) par_area 337 | FROM data p 338 | JOIN data c ON ST_Contains(p.geom, ST_PointOnSurface(c.geom)) 339 | WHERE ST_Area(p.geom) > ST_Area(c.geom) 340 | ), 341 | -- extract direct containment links, by choosing parent with min area 342 | pcrel AS ( SELECT DISTINCT ON (idch) idpar, idch 343 | FROM contains ORDER BY idch, par_area ASC 344 | ), 345 | -- compute paths as strings 346 | pcpath(id, path) AS ( 347 | SELECT 'A' AS id, 'A' AS path 348 | UNION ALL 349 | SELECT idch AS id, path || ',' || idch 350 | FROM pcpath JOIN pcrel ON pcpath.id = pcrel.idpar 351 | ) 352 | SELECT * FROM pcpath; 353 | ``` 354 | 355 | 356 | ## Polygon / Line 357 | 358 | ### Find Start Points of Rivers and Headwater polygons 359 | 360 | 361 | 362 | ### Find routes which terminate in Polygons but do not cross them 363 | 364 | 365 | ### Find Lines that touch Polygon at both ends 366 | 367 | 368 | ### Find Lines that touch but do not cross Polygons 369 | 370 | 371 | ![](https://i.stack.imgur.com/nkhe3.png) 372 | 373 | ```sql 374 | SELECT lines.geom 375 | FROM lines, polygons 376 | WHERE ST_Touches(lines.geom, polygons.geom) AND 377 | NOT EXISTS (SELECT 1 FROM polygons p2 WHERE ST_Crosses(lines.geom, p2.geom)); 378 | ``` 379 | 380 | ## Line / Line 381 | 382 | ### Find LineStrings with Common Segments 383 | 384 | 385 | ```sql 386 | SELECT ST_Relate('LINESTRING(0 0, 2 0)'::geometry, 387 | 'LINESTRING(1 0, 2 0)'::geometry, 388 | '1********'); 389 | ``` 390 | 391 | ## Line / Point 392 | 393 | ### Test if Point is on a Line 394 | 395 | 396 | 397 | 398 | -------------------------------------------------------------------------------- /query/query-stat.md: -------------------------------------------------------------------------------- 1 | --- 2 | parent: Querying 3 | --- 4 | 5 | # Spatial Statistics 6 | {: .no_toc } 7 | 8 | 1. TOC 9 | {:toc} 10 | 11 | ## Count Points contained in Polygons 12 | 13 | #### Solution - LATERAL 14 | Good use case for JOIN LATERAL 15 | ```sql 16 | SELECT bg.geoid, bg.geom, bg.total_pop AS total_population, 17 | bg.med_inc AS median_income, 18 | t.numbirds 19 | FROM bg_pop_income bg 20 | JOIN LATERAL 21 | (SELECT COUNT(1) as numbirds 22 | FROM bird_loc bl 23 | WHERE ST_within(bl.loc, bg.geom)) AS t ON true; 24 | ``` 25 | #### Solution using GROUP BY 26 | Almost certainly less performant 27 | ```sql 28 | SELECT bg.geoid, bg.geom, bg.total_pop, bg.med_inc, 29 | COUNT(bl.global_unique_identifier) AS num_bird_counts 30 | FROM bg_pop_income bg 31 | LEFT OUTER JOIN bird_loc bl ON ST_Contains(bg.geom, bl.loc) 32 | GROUP BY bg.geoid, bg.geom, bg.total_pop, bg.med_inc; 33 | ``` 34 | ## Count points from two tables which lie inside polygons 35 | https://stackoverflow.com/questions/59989829/count-number-of-points-from-two-datasets-contained-by-neighbourhood-polygons-u 36 | 37 | ## Count polygons which lie within two layers of polygons 38 | https://gis.stackexchange.com/questions/115881/how-many-a-features-that-fall-both-in-the-b-polygons-and-c-polygons-are-for-each 39 | 40 | ***(Question is for ArcGIS; would be interesting to provide a PostGIS answer)*** 41 | 42 | ## Count number of adjacent polygons in a coverage 43 | 44 | (First query) 45 | ```sql 46 | SELECT a.id, a.geom, a.codistat, a.name, num_adj 47 | FROM municipal a 48 | JOIN LATERAL (SELECT COUNT(1) num_adj 49 | FROM municipal b 50 | WHERE ST_Intersects(a.geom, b.geom) 51 | ) t ON true; 52 | ``` 53 | 54 | ## Count number of adjacent polygons in a coverage connected by a line 55 | 56 | ```sql 57 | SELECT a.id, a.geom, a.codistat, a.name, num_adj 58 | FROM municipal a 59 | JOIN LATERAL (SELECT COUNT(1) num_adj 60 | FROM municipal b 61 | JOIN way w 62 | ON ST_Intersects(b.geom, w.geom) 63 | WHERE ST_Intersects(a.geom, b.geom) 64 | AND ST_Intersects(a.geom, w.geom) 65 | ) t ON true; 66 | ``` 67 | 68 | ## Find Median of values in a Polygon neighbourhood in a Polygonal Coverage 69 | 70 | 71 | ## Sum length of Lines intersecting Polygons 72 | ```sql 73 | SELECT county, SUM(ST_Length(ST_Intersection(counties.geom,routes.geom))) 74 | FROM counties 75 | JOIN routes ON ST_Intersects(counties.geom, routes.geom) 76 | GROUP BY county; 77 | ``` 78 | See following (but answers are not great) 79 | 80 | 81 | 82 | ## Find geometry with maximum value in groups 83 | 84 | 85 | From a table containing a group_id, a value and a geometry, find the record in each group which has the maximum value in the group. 86 | 87 | NOTE: This is a classic SQL problem, not unique to spatial data. 88 | 89 | ### Using ROW_NUMBER window function 90 | ```sql 91 | SELECT id, val, geom 92 | FROM ( 93 | SELECT *, ROW_NUMBER() OVER ( PARTITION BY id ORDER BY val DESC ) AS _rank 94 | FROM tbl 95 | ) q 96 | WHERE _rank = 1; 97 | ``` 98 | ### Using self-join 99 | ```sql 100 | SELECT a.id, MAX( a.val ), b.geom 101 | FROM tbl a 102 | GROUP BY id 103 | LEFT JOIN tbl b ON a.id, b.id; 104 | ``` 105 | 106 | ## Find extremal points of Polygons 107 | 108 | 109 | Extract unique points of polygons using `ST_DumpPoints(ST_RemoveRepeatedPoints(ST_Points`, then use `RANK` window functions 110 | to extract points with maximmal/minimal X and Y. 111 | 112 | **Note:** it might be more efficient to use the `path` information from `ST_DumpPoints` to eliminate the duplicate start and end point. 113 | 114 | ```sql 115 | WITH data(id, geom) AS (VALUES 116 | (1, 'POLYGON((-71.1776585052917 42.3902909739571,-71.1776820268866 42.3903701743239, -71.1776063012595 42.3903825660754,-71.1775826583081 42.3903033653531,-71.1776585052917 42.3902909739571))'::geometry) 117 | ,(2, 'POLYGON ((-71.1775 42.3902, -71.1773 42.3908, -71.1769 42.3905, -71.177 42.39, -71.1775 42.3902))'::geometry) 118 | ), 119 | pts AS (SELECT id, (ST_DumpPoints(ST_RemoveRepeatedPoints(ST_Points(geom)))).geom FROM data), 120 | rank AS (SELECT id, ST_AsText(geom), 121 | RANK() OVER (PARTITION BY id ORDER BY ST_X(geom) DESC) AS rank_max_x, 122 | RANK() OVER (PARTITION BY id ORDER BY ST_X(geom) ASC) AS rank_min_x, 123 | RANK() OVER (PARTITION BY id ORDER BY ST_Y(geom) DESC) AS rank_max_y, 124 | RANK() OVER (PARTITION BY id ORDER BY ST_Y(geom) ASC) AS rank_min_y 125 | FROM pts 126 | ) 127 | SELECT * FROM rank 128 | WHERE rank_max_x = 1 OR rank_min_x = 1 OR rank_max_y = 1 OR rank_min_y = 1; 129 | ``` 130 | --------------------------------------------------------------------------------