Today most common SQL-based relational database management systems (DBMS) like PostgreSQL, MySQL, MariaDB, SQL Server and Oracle offer functionality to efficiently store and query JSON data in one form or another, with varying syntax. While a standard named SQL/JSON is in the works, it is not yet fully supported by all of these DBMS. This blog post is specific to PostgreSQL.
JSON data types
In PostgreSQL there are two data types for JSON columns: json
and jsonb
. The former stores JSON data as-is with any formatting preserved, while the latter stores JSON in a decomposed binary format. Operations on data in jsonb
format are potentially more efficient.
We’ll use the jsonb
data type in the following example to store a sequence of events, for example for an event sourcing based application, in a table.
CREATE TABLE events (date TIMESTAMP NOT NULL, event JSONB NOT NULL);
JSON literals look like string literals. Let’s insert some events:
INSERT INTO events (date, event) VALUES (NOW(), '{"type": "add_shelf", "payload": {"id": 1}}'), (NOW(), '{"type": "add_book", "payload": {"title": "Ulysses", "shelf": 1}}'), (NOW(), '{"type": "add_book", "payload": {"title": "Moby Dick", "shelf": 1}}'), (NOW(), '{"type": "add_shelf", "payload": {"id": 2}}'), (NOW(), '{"type": "add_book", "payload": {"title": "Don Quixote", "shelf": 2}}');
Querying
PostgreSQL has two operators for navigating a JSON structure: ->
and ->>
. The former accesses an object field by key and the latter accesses an object field as text. These operators can be used both in the SELECT clause and the WHERE clause:
SELECT event->>'type' AS type FROM events;
type add_shelf add_book add_book add_shelf
SELECT event FROM events WHERE event->>'type'='add_book' AND event->'payload'->>'shelf'='1';
event {"type":"add_book","payload":{"shelf":1,"title":"Ulysses"}} {"type":"add_book","payload":{"shelf":1,"title":"Moby Dick"}}
Note that in the example above the value of "shelf"
is compared to a string literal ('1'
). In order to treat the value as a number we have to use the CAST function, and then we can use numerical comparison operators:
SELECT event FROM events WHERE CAST( event->'payload'->>'shelf' AS INTEGER ) > 1;
event {"type":"add_book","payload":{"shelf":2,"title":"Don Quixote"}}
Updating
Updating JSON object fields is a bit more complicated. It is only possible with the jsonb
data type and can be done via the JSONB_SET
function, which takes four arguments:
1) the original JSON,
2) a path specifying which object fields should be updated,
3) a jsonb
value, which is the new value, and
4) a boolean flag that specifies if missing fields should be created.
In this example we convert all the event "type"
fields from lower case to upper case:
UPDATE events SET event=JSONB_SET( event, '{type}', TO_JSONB(UPPER(event->>'type')), false );
PostgreSQL provides a lot more operators and functions for working with JSON data. This post only covered the most basic ones. See the PostgreSQL JSON reference for more.
2 thoughts on “Working with JSON data in PostgreSQL”