PostgreSQL Tutorial

  • Home
  • Administration
  • Views
  • Triggers
  • Stored Procedures
  • Interfaces
    • PostgreSQL PHP
    • PostgreSQL Python
    • PostgreSQL JDBC
Home / PostgreSQL Tutorial / PostgreSQL hstore

PostgreSQL hstore

Summary: in this tutorial, we will show you how to work with PostgreSQL hstore data type.

The hstore module implements hstore data type for storing key-value pairs in a single value. The hstore data type is very useful in many cases, such as semi-structured data, or rows with many attributes that are rarely queried. Notice that keys and values are just text strings only.

Enable PostgreSQL hstore extension

Before working with the hstore data type, you need to enable the hstore extension, which loads the contrib module to your PostgreSQL instance.

1
CREATE EXTENSION hstore;

Create a table with hstore data type

We create a table named books that has three columns:

  •  id is the primary key that identifies the book.
  •  title is 0the title of the products
  •  attr stores attributes of the book such as isbn, weight, paper-back, etc. The data type of the attr column is hstore.

We use the CREATE TABLE statement to create the books table as follows:

1
2
3
4
5
CREATE TABLE books (
id serial primary key,
title VARCHAR (255),
attr hstore
);

Insert data into PostgreSQL hstore column

We use the INSERT statement to insert data into the hstore column as follows:

1
2
3
4
5
6
7
8
9
10
INSERT INTO books (title, attr)
VALUES
(
'PostgreSQL Tutorial',
'"paperback" => "243",
   "publisher" => "postgresqltutorial.com",
   "language"  => "English",
   "ISBN-13"   => "978-1449370000",
"weight"    => "11.2 ounces"'
);

The data that we insert into the hstore column is a list of comma separated key =>value pairs. Both keys and values are quoted using double quotes (“”).

Let’s insert one more row.

1
2
3
4
5
6
7
8
9
10
11
INSERT INTO books (title, attr)
VALUES
(
'PostgreSQL Cheat Sheet',
'
"paperback" => "5",
"publisher" => "postgresqltutorial.com",
"language"  => "English",
"ISBN-13"   => "978-1449370001",
"weight"    => "1 ounces"'
);

Query data from a hstore column

Querying data from a hstore column is similar to querying data from column with native data type using SELECT statement as follows:

1
2
3
4
SELECT
attr
FROM
books;

postgresql hstore query

Query value for a specific key

Postgresql hstore provides the -> operator to query value of a specific key from a hstore column. For example, if we want to know ISBN-13 of all available books in the books table, we can use the -> operator as follows:

1
2
3
4
SELECT
attr -> 'ISBN-13' AS isbn
FROM
books;

postgresql hstore query key

Use value in the WHERE clause

You can use the -> operator in the WHERE clause to filter the rows whose values of the hstore column match the input value. For example, the following  query retrieves the title and weight of a book that has ISBN-13 value matches 978-1449370000:

1
2
3
4
5
6
SELECT
attr -> 'weight' AS weight
FROM
books
WHERE
attr -> 'ISBN-13' = '978-1449370000'

postgresql hstore WHERE clause

Add key-value pairs to existing rows

With hstore column, we can easily add a new key-value pair to existing rows e.g., we can add free shipping key to the attr column of the books table as follows:

1
2
UPDATE books
SET attr = attr || '"freeshipping"=>"yes"' :: hstore;

Now, we can check to see if the “freeshipping” => “yes”  pair has been added successfully.

1
2
3
4
5
SELECT
title,
        attr -> 'freeshipping' AS freeshipping
FROM
books;

postgresql hstore add key-value

Update existing key-value pair

You can update existing key-value pair using the UPDATE statement. The following statement updates the value of the "freeshipping" key to "no".

1
2
UPDATE books
SET attr = attr || '"freeshipping"=>"no"' :: hstore;

Remove existing key-value pair

PostgreSQL allows you to remove existing key-value pair from an hstore column. For example, the following statement removes the "freeshipping"=>"no" key-value pair in the attr column.

1
2
UPDATE books
SET attr = delete(attr, 'freeshipping');

Check for a specific key in hstore column

You can check for a specific key in an hstore column using the ? operator in the WHERE clause. For example, the following statement returns all rows with attr contains publisher key.

1
2
3
4
5
6
7
8
SELECT
  title,
  attr->'publisher' as publisher,
  attr
FROM
books
WHERE
attr ? 'publisher';

postgesql hstore check key

Check for a key-value pair

You can query based on hstore key-value pair using the @> operator. The following statement retrieves all rows which attr column contains a key-value pair that matches "weight"=>"11.2 ounces".

1
2
3
4
5
6
SELECT
title
FROM
books
WHERE
attr @> '"weight"=>"11.2 ounces"' :: hstore;

postgresql hstore check key-pair

Query rows that contain multiple specified keys

You can query the rows whose hstore column contain multiple keys using ?& operator. For example, you can get books where attr column contains both language and weight keys.

1
2
3
4
5
6
SELECT
title
FROM
books
WHERE
attr ?& ARRAY [ 'language', 'weight' ];

postgresql hstore check multiple keys

To check if a row whose hstore column contains any key you use the ?| operator instead of the ?& operator.

Get all keys from a hstore column

To get all keys from an hstore column, you use the akeys() function as follows:

1
2
3
4
SELECT
akeys (attr)
FROM
books;

postgresql hstore akeys function

Or you can use the  skey() function if you want PostgreSQL to return the result as a set.

1
2
3
4
SELECT
skeys (attr)
FROM
books;

postgresql hstore skeys function

Get all values from an hstore column

Like keys, you can get all values from an hstore column using the  avals() function in the form of arrays.

1
2
3
4
SELECT
avals (attr)
FROM
books;

postgresql hstore avals function

Or you can use the  svals() function if you want to get the result as a set.

1
2
3
4
SELECT
svals (attr)
FROM
books;

postgresql hstore svals

Convert hstore data to JSON

PostgreSQL provides the hstore_to_json() function to convert hstore data to JSON. See the following statement:

1
2
3
4
5
SELECT
  title,
  hstore_to_json (attr) json
FROM
  books;

postgresql hstore to json

Convert hstore data to sets

To convert hstore data to sets, you use the  each() function as follows:

1
2
3
4
5
SELECT
title,
(EACH(attr) ).*
FROM
books;

postgresql hstore to sets

In this tutorial, we have shown you how to work with PostgreSQL hstore data type and introduced you to the most useful operations that you can perform against hstore data type.

Related Tutorials

  • PostgreSQL JSON
Previous Tutorial: PostgreSQL Array
Next Tutorial: PostgreSQL JSON

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

  • PostgreSQL Recursive View
  • Learn PostgreSQL Recursive Query By Example
  • Creating Updatable Views Using the WITH CHECK OPTION Clause
  • PostgreSQL Upsert Using INSERT ON CONFLICT statement
  • How to Generate a Random Number in A Range
  • Using PostgreSQL ADD COLUMN to Add One or More Columns To a Table
  • PostgreSQL Character Types: CHAR, VARCHAR, and TEXT
  • Using PostgreSQL SERIAL To Create Auto-increment Column
  • PostgreSQL Boolean Data Type with Practical Examples
  • Understanding PostgreSQL Timestamp Data Types

More Tutorials

  • PostgreSQL PHP
  • PostgreSQL Python
  • PostgreSQL JDBC
  • PostgreSQL Functions
  • PostgreSQL Resources

Site Info

  • Home
  • About Us
  • Contact Us
  • Privacy Policy

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