GeoJSON Features from PostGIS
27 Mar 2019Every once in a while, someone comes to me and says:
Sure, it’s handy to use ST_AsGeoJSON to convert a geometry into a JSON equivalent, but all the web clients out there like to receive full GeoJSON Features and I end up writing boilerplate to convert database rows into GeoJSON. Also, the only solution I can find on the web is scary and complex. Why don’t you have a
row_to_geojson
function?
And the answer (still) is that working with rows is fiddly and I don’t really feel like it.
However! It turns out that, with the tools for JSON manipulation already in PostgreSQL and a little scripting it’s possible to make a passable function to do the work.
Start with a simple table.
You can convert any row into a JSON structure using the to_jsonb() function.
SELECT to_jsonb(mytable.*) FROM mytable;
{"pk": 1, "geom": "010100000000000000000000400000000000004140", "name": "Peter", "size": 1}
{"pk": 2, "geom": "010100000000000000000014400000000000C05040", "name": "Paul", "size": 2}
That’s actually all the information we need to create a GeoJSON feature, it just needs to be re-arranged. So let’s make a little utility function to re-arrange it.
Voila! Now we can turn any relation into a proper GeoJSON “Feature” with just one(ish) function call.
SELECT rowjsonb_to_geojson(to_jsonb(mytable.*)) FROM mytable;
{"type": "Feature", "geometry": {"type": "Point", "coordinates": [2, 34]}, "properties": {"pk": 1, "name": "Peter", "size": 1}}
{"type": "Feature", "geometry": {"type": "Point", "coordinates": [5, 67]}, "properties": {"pk": 2, "name": "Paul", "size": 2}}
Postscript
You might be wondering why I made my function take in a jsonb
input instead of a record
, for a perfect row_to_geojson
analogue to row_to_json
. The answer is, the PL/PgSQL planner caches types, including the materialized types of the record
parameter, on the first evaluation, which makes it impossible to use the same function for multiple tables. This is “too bad (tm)” but fortunately it is an easy workaround to just change the input to jsonb
using to_json()
before calling our function.