|
| 1 | +## PostgreSQL PostGIS 3 st_asgeojson |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2019-08-03 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , PostGIS , geojson , record , feature , geometry |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +原文 |
| 16 | + |
| 17 | +https://info.crunchydata.com/blog/postgis-3-geojson-st-asgeojson |
| 18 | + |
| 19 | +geojson是服务端与客户端geo数据传输等一种格式,格式参考RFC定义 |
| 20 | + |
| 21 | +https://tools.ietf.org/html/rfc7946 |
| 22 | + |
| 23 | +``` |
| 24 | + 2. GeoJSON Text . . . . . . . . . . . . . . . . . . . . . . . . 6 |
| 25 | + 3. GeoJSON Object . . . . . . . . . . . . . . . . . . . . . . . 6 |
| 26 | + 3.1. Geometry Object . . . . . . . . . . . . . . . . . . . . . 7 |
| 27 | + 3.1.1. Position . . . . . . . . . . . . . . . . . . . . . . 7 |
| 28 | + 3.1.2. Point . . . . . . . . . . . . . . . . . . . . . . . . 8 |
| 29 | + 3.1.3. MultiPoint . . . . . . . . . . . . . . . . . . . . . 8 |
| 30 | + 3.1.4. LineString . . . . . . . . . . . . . . . . . . . . . 8 |
| 31 | + 3.1.5. MultiLineString . . . . . . . . . . . . . . . . . . . 8 |
| 32 | + 3.1.6. Polygon . . . . . . . . . . . . . . . . . . . . . . . 9 |
| 33 | + 3.1.7. MultiPolygon . . . . . . . . . . . . . . . . . . . . 9 |
| 34 | + 3.1.8. GeometryCollection . . . . . . . . . . . . . . . . . 9 |
| 35 | + 3.1.9. Antimeridian Cutting . . . . . . . . . . . . . . . . 10 |
| 36 | + 3.1.10. Uncertainty and Precision . . . . . . . . . . . . . . 11 |
| 37 | + 3.2. Feature Object . . . . . . . . . . . . . . . . . . . . . 11 |
| 38 | + 3.3. FeatureCollection Object . . . . . . . . . . . . . . . . |
| 39 | +``` |
| 40 | + |
| 41 | +PostGIS 3以前,st_asgeojson仅支持geometry输入,构造geojson格式比较麻烦 |
| 42 | + |
| 43 | +http://postgis.net/docs/manual-2.5/ST_AsGeoJSON.html |
| 44 | + |
| 45 | +``` |
| 46 | +text ST_AsGeoJSON(geometry geom, integer maxdecimaldigits=15, integer options=0); |
| 47 | + |
| 48 | +text ST_AsGeoJSON(geography geog, integer maxdecimaldigits=15, integer options=0); |
| 49 | + |
| 50 | +select row_to_json(fc) |
| 51 | +from ( |
| 52 | + select |
| 53 | + 'FeatureCollection' as "type", |
| 54 | + array_to_json(array_agg(f)) as "features" |
| 55 | + from ( |
| 56 | + select |
| 57 | + 'Feature' as "type", |
| 58 | + ST_AsGeoJSON(ST_Transform(way, 4326), 6) :: json as "geometry", |
| 59 | + ( |
| 60 | + select json_strip_nulls(row_to_json(t)) |
| 61 | + from ( |
| 62 | + select |
| 63 | + osm_id, |
| 64 | + "natural", |
| 65 | + place |
| 66 | + ) t |
| 67 | + ) as "properties" |
| 68 | + from planet_osm_point |
| 69 | + where |
| 70 | + "natural" is not null |
| 71 | + or place is not null |
| 72 | + limit 10 |
| 73 | + ) as f |
| 74 | +) as fc; |
| 75 | + st_asgeojson |
| 76 | +----------------------------------------------------------------------------------------------------------- |
| 77 | +{"type":"FeatureCollection","features":[{"type":"Feature","geometry":{"type":"Point","coordinates":[23.569251,51.541599]},"properties":{"osm_id":3424148658,"place":"locality"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.625174,51.511718]},"properties":{"osm_id":4322036818,"place":"locality"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.613928,51.5417]},"properties":{"osm_id":242979330,"place":"hamlet"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.586361,51.563272]},"properties":{"osm_id":3424148656,"place":"locality"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.605488,51.553886]},"properties":{"osm_id":242979323,"place":"village"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.6067,51.57609]},"properties":{"osm_id":242979327,"place":"village"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.636533,51.575683]},"properties":{"osm_id":5737800420,"place":"locality"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.656733,51.518733]},"properties":{"osm_id":5737802397,"place":"locality"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.672542,51.504584]},"properties":{"osm_id":242979320,"place":"hamlet"}},{"type":"Feature","geometry":{"type":"Point","coordinates":[23.574094,51.63389]},"properties":{"osm_id":242979333,"place":"village"}}]} |
| 78 | + |
| 79 | +SELECT ST_AsGeoJSON(geom) from fe_edges limit 1; |
| 80 | + st_asgeojson |
| 81 | +----------------------------------------------------------------------------------------------------------- |
| 82 | + |
| 83 | +{"type":"MultiLineString","coordinates":[[[-89.734634999999997,31.492072000000000], |
| 84 | +[-89.734955999999997,31.492237999999997]]]} |
| 85 | +(1 row) |
| 86 | +``` |
| 87 | + |
| 88 | +3以后,st_asgeojson支持record输入,默认第一列为geo类型,其他列的内容合并到properties中。 |
| 89 | + |
| 90 | +http://postgis.net/docs/manual-dev/ST_AsGeoJSON.html |
| 91 | + |
| 92 | +text ST_AsGeoJSON(record feature, text geomcolumnname, integer maxdecimaldigits=15, boolean pretty_bool=false); |
| 93 | + |
| 94 | + |
| 95 | +The ST_AsGeoJSON(record) function looks at the input tuple, and takes the first column of type geometry to convert into a GeoJSON geometry. The rest of the columns are added to the GeoJSON features in the properties member. |
| 96 | + |
| 97 | +例子 |
| 98 | + |
| 99 | +``` |
| 100 | +SELECT ST_AsGeoJSON(subq.*) AS geojson |
| 101 | +FROM ( |
| 102 | + SELECT ST_Centroid(geom), type, admin |
| 103 | + FROM countries |
| 104 | + WHERE name = 'Canada' |
| 105 | +) AS subq |
| 106 | +{"type": "Feature", |
| 107 | + "geometry": { |
| 108 | + "type":"Point", |
| 109 | + "coordinates":[-98.2939042718784,61.3764628013483] |
| 110 | + }, |
| 111 | + "properties": { |
| 112 | + "type": "Sovereign country", |
| 113 | + "admin": "Canada" |
| 114 | + } |
| 115 | +} |
| 116 | +``` |
| 117 | + |
| 118 | +http://postgis.net/docs/manual-dev/ST_AsGeoJSON.html |
| 119 | + |
| 120 | +``` |
| 121 | +To build FeatureCollection: |
| 122 | + |
| 123 | +select json_build_object( |
| 124 | + 'type', 'FeatureCollection', |
| 125 | + 'features', json_agg(ST_AsGeoJSON(t.*)::json) |
| 126 | + ) |
| 127 | +from ( values (1, 'one', 'POINT(1 1)'::geometry), |
| 128 | + (2, 'two', 'POINT(2 2)'), |
| 129 | + (3, 'three', 'POINT(3 3)') |
| 130 | + ) as t(id, name, geom); |
| 131 | +{"type" : "FeatureCollection", "features" : [{"type": "Feature", "geometry": {"type":"Point","coordinates":[1,1]}, "properties": {"id": 1, "name": "one"}}, {"type": "Feature", "geometry": {"type":"Point","coordinates":[2,2]}, "properties": {"id": 2, "name": "two"}}, {"type": "Feature", "geometry": {"type":"Point","coordinates":[3,3]}, "properties": {"id": 3, "name": "three"}}]} |
| 132 | +To get Features as records: |
| 133 | + |
| 134 | +SELECT ST_AsGeoJSON(t.*) |
| 135 | +FROM (VALUES |
| 136 | + (1, 'one', 'POINT(1 1)'::geometry), |
| 137 | + (2, 'two', 'POINT(2 2)'), |
| 138 | + (3, 'three', 'POINT(3 3)')) |
| 139 | +AS t(id, name, geom); |
| 140 | + st_asgeojson |
| 141 | +----------------------------------------------------------------------------------------------------------------- |
| 142 | + {"type": "Feature", "geometry": {"type":"Point","coordinates":[1,1]}, "properties": {"id": 1, "name": "one"}} |
| 143 | + {"type": "Feature", "geometry": {"type":"Point","coordinates":[2,2]}, "properties": {"id": 2, "name": "two"}} |
| 144 | + {"type": "Feature", "geometry": {"type":"Point","coordinates":[3,3]}, "properties": {"id": 3, "name": "three"}} |
| 145 | +``` |
| 146 | + |
| 147 | + |
| 148 | +## 参考 |
| 149 | +https://info.crunchydata.com/blog/postgis-3-geojson-st-asgeojson |
| 150 | + |
| 151 | + |
| 152 | + |
| 153 | +<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a> |
| 154 | + |
| 155 | + |
| 156 | +## [digoal's 大量PostgreSQL文章入口](https://github.com/digoal/blog/blob/master/README.md "22709685feb7cab07d30f30387f0a9ae") |
| 157 | + |
| 158 | + |
| 159 | +## [免费领取阿里云RDS PostgreSQL实例、ECS虚拟机](https://free.aliyun.com/ "57258f76c37864c6e6d23383d05714ea") |
| 160 | + |
0 commit comments