PostgreSQL Tutorial

  • Home
  • Stored Procedures
  • Triggers
  • Views
  • Interfaces
    • PostgreSQL PHP
    • PostgreSQL Python
    • PostgreSQL JDBC
  • Functions
Home / PostgreSQL Tutorial / PostgreSQL JSON

PostgreSQL JSON

Summary: in this tutorial, we will show you how to work with PostgreSQL JSON data type. In addition, we will introduce you to some of the most common PostgreSQL JSON operators and functions for handling JSON data.

JSON stands for JavaScript Object Notation. JSON is an open standard format that consists of key-value pairs. The main usage of JSON is to transport data between a server and web application. Unlike other formats, JSON is human-readable text.

PostgreSQL supports native JSON data type since version 9.2. It provides many functions and operators  for manipulating JSON data.

Let’s get started by creating a new table for practicing with JSON data type.

1
2
3
4
CREATE TABLE orders (
ID serial NOT NULL PRIMARY KEY,
info json NOT NULL
);

The orders table consists of two columns:

  1. The id column is the primary key column that identifies the order.
  2. The info column stores the data in the form of JSON.

Insert JSON data

To insert data into a JSON column, you have to ensure that data is in a valid JSON format.  The following INSERT statement inserts a new row into the orders table.

1
2
3
4
5
INSERT INTO orders (info)
VALUES
(
'{ "customer": "John Doe", "items": {"product": "Beer","qty": 6}}'
);

It means John Doe bought 6 bottle of beers.

Let’s insert multiple rows at the same time.

1
2
3
4
5
6
7
8
9
10
11
INSERT INTO orders (info)
VALUES
(
'{ "customer": "Lily Bush", "items": {"product": "Diaper","qty": 24}}'
),
(
'{ "customer": "Josh William", "items": {"product": "Toy Car","qty": 1}}'
),
(
'{ "customer": "Mary Clark", "items": {"product": "Toy Train","qty": 2}}'
);

Querying JSON data

To query JSON data, you use the SELECT statement, which is similar to querying other native data types:

1
2
3
4
SELECT
info
FROM
orders;

postgresql json query data

PostgreSQL returns a result set in the form of JSON.

PostgreSQL provides two native operators -> and ->> to help you query JSON data.

  • The operator -> returns JSON object field by key.
  • The operator ->> returns JSON object field by text.

The following query uses operator -> to get all customers in form of JSON:

1
2
3
4
SELECT
info -> 'customer' AS customer
FROM
orders;

postgresql JSON native operator

And the following query uses operator ->> to get all customers in form of text:

1
2
3
4
SELECT
info ->> 'customer' AS customer
FROM
orders;

postgresql json text operator

Because -> operator returns a JSON object, you can chain it with the operator ->> to retrieve a specific node. For example, the following statement returns all products sold:

1
2
3
4
5
6
SELECT
info -> 'items' ->> 'product' as product
FROM
orders
ORDER BY
product;

postgresql json operator chain

First  info -> 'items' returns items as JSON objects. And then info->'items'->>'product' returns all products as text.

Use JSON operator in WHERE clause

We can use the JSON operators in WHERE clause to filter the returning rows. For example, to find out who bought Diaper, we use the following query:

1
2
3
4
5
6
SELECT
info ->> 'customer' AS customer
FROM
orders
WHERE
info -> 'items' ->> 'product' = 'Diaper'

postgresql json opeartor in where clause

To find out who bought 2 products at a time, we use the following query:

1
2
3
4
5
6
7
8
9
SELECT
info ->> 'customer' AS customer,
info -> 'items' ->> 'product' AS product
FROM
orders
WHERE
CAST (
info -> 'items' ->> 'qty' AS INTEGER
) = 2

postgresql json operator cast in where clause

Notice that we used the type cast to convert the qty field into INTEGER type and compare it with 2.

Apply aggregate functions to JSON data

We can apply aggregate functions such as MIN, MAX, AVERAGE, SUM, etc., to JSON data. For example, the following statement returns minimum quantity, maximum quantity, average quantity and the total quantity of products sold.

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
SELECT
MIN (
CAST (
info -> 'items' ->> 'qty' AS INTEGER
)
),
MAX (
CAST (
info -> 'items' ->> 'qty' AS INTEGER
)
),
SUM (
CAST (
info -> 'items' ->> 'qty' AS INTEGER
)
),
AVG (
CAST (
info -> 'items' ->> 'qty' AS INTEGER
)
)
 
FROM
orders

postgresql json aggregate function

PostgreSQL JSON functions

PostgreSQL provides us with some functions to help you process JSON data.

json_each function

The json_each() function allows us to expand the outermost JSON object into a set of key-value pairs. See the following statement:

1
2
3
4
SELECT
json_each (info)
FROM
orders;

postgresql json json_each function

If you want to get a set of key-value pairs as text, you use the json_each_text() function instead.

json_object_keys function

To get a set of keys in the outermost JSON object, you use the json_object_keys() function. The following query returns all keys of the nested items object in the info column

1
2
3
4
SELECT
json_object_keys (info->'items')
FROM
orders;

postgresql json_object_keys function

json_typeof function

The json_typeof() function returns type of the outermost JSON value as a string. It can be number, boolean, null, object, array, and string.

The following query return the data type of the items:

1
2
3
4
SELECT
json_typeof (info->'items')
FROM
orders;

postgresql json_typeof

The following query returns the data type of the qty field of the nested items JSON object.

1
2
3
4
SELECT
json_typeof (info->'items'->'qty')
FROM
orders;

postgresql json_typeof function

There are more PostgreSQL JSON functions if you want to dig deeper.

In this tutorial, we have shown you how to work with PostgreSQL JSON data type. We showed you some of the most important JSON operators and functions that help you process JSON data more effectively.

Related Tutorials

  • PostgreSQL hstore
Previous Tutorial: PostgreSQL hstore
Next Tutorial: A Look at PostgreSQL User-defined Data Types

PostgreSQL Quick Start

  • What is PostgreSQL?
  • Install PostgreSQL
  • Connect to Database
  • Download PostgreSQL Sample Database
  • Load Sample Database
  • Explore Server and Database Objects

PostgreSQL Fundamentals

  • PostgreSQL Select
  • PostgreSQL Order By
  • PostgreSQL Select Distinct
  • PostgreSQL Where
  • PostgreSQL LIMIT
  • PostgreSQL IN
  • PostgreSQL Between
  • PostgreSQL Like
  • PostgreSQL Inner Join
  • PostgreSQL Left Join
  • PostgreSQL Full Outer Join
  • PostgreSQL Cross Join
  • PostgreSQL Natural Join
  • PostgreSQL Group By
  • PostgreSQL Having
  • PostgreSQL Union
  • PostgreSQL Intersect
  • PostgreSQL Except
  • PostgreSQL Subquery
  • PostgreSQL Insert
  • PostgreSQL Update
  • PostgreSQL Delete
  • PostgreSQL Data Types
  • PostgreSQL Create Table
  • PostgreSQL Alter Table
  • PostgreSQL Drop Table
  • PostgreSQL Truncate Table
  • PostgreSQL CHECK Constraint
  • PostgreSQL Not-Null Constraint
  • PostgreSQL Foreign Key
  • PostgreSQL Primary Key
  • PostgreSQL UNIQUE Constraint

About PostgreSQL Tutorial

PostgreSQLTutorial.com is a website dedicated to developers and database administrators who are working on PostgreSQL database management system.

We constantly publish useful PostgreSQL tutorials to keep you up-to-date with the latest PostgreSQL features and technologies. All PostgreSQL tutorials are simple, easy-to-follow and practical.

Recent PostgreSQL Tutorials

  • How To Change The Password of a PostgreSQL User
  • PostgreSQL AGE Function
  • PostgreSQL DATE_PART Function
  • PostgreSQL List Users
  • PostgreSQL NOW Function
  • PostgreSQL DATE_TRUNC Function
  • PostgreSQL TO_DATE Function: Convert String to Date
  • A Look at PostgreSQL User-defined Data Types
  • PostgreSQL Copy Database Made Easy
  • How to Get Table, Database, Indexes, Tablespace, and Value Size in PostgreSQL

More Tutorials

  • PostgreSQL Cheat Sheet
  • PostgreSQL Administration
  • PostgreSQL PHP
  • PostgreSQL Python
  • PostgreSQL JDBC
  • PostgreSQL Resources

Site Info

  • Home
  • About Us
  • Contact Us
  • Privacy Policy

Copyright © 2017 by PostgreSQL Tutorial Website. All Rights Reserved.