2ndQuadrant is now part of EDB

Bringing together some of the world's top PostgreSQL experts.

2ndQuadrant | PostgreSQL
Mission Critical Databases
  • Contact us
  • Support & Services
    • Support
      • 24/7 PostgreSQL Support
      • Developer Support
    • DBA Services
      • Remote DBA
      • Database Monitoring
    • Consulting Services
      • Health Check
      • Performance Tuning
      • Database Security Audit
      • PostgreSQL Upgrade
    • Migration Services
      • Migrate to PostgreSQL
      • Migration Assessment
  • Products
    • Postgres-BDR ®
    • PostgreSQL High Availability
    • Kubernetes Operators for BDR & PostgreSQL
    • Managed PostgreSQL in the Cloud
    • Installers
      • Postgres Installer
      • 2UDA
    • 2ndQPostgres
    • pglogical
    • Barman
    • repmgr
    • OmniDB
    • SQL Firewall
    • Postgres-XL
  • Downloads
    • Installers
      • Postgres Installer
      • 2UDA – Unified Data Analytics
    • Whitepapers
      • Business Case for PostgreSQL Support
      • AlwaysOn Postgres
      • PostgreSQL with High Availability
      • Security Best Practices
      • BDR
    • Case Studies
      • Performance Tuning
        • BenchPrep
        • tastyworks
      • Distributed Clusters
        • ClickUp
        • European Space Agency (ESA)
        • Telefónica del Sur
        • Animal Logic
      • Database Administration
        • Agilis Systems
      • Professional Training
        • Met Office
        • London & Partners
      • Database Upgrades
        • Alfred Wegener Institute (AWI)
      • Database Migration
        • International Game Technology (IGT)
        • Healthcare Software Solutions (HSS)
        • Navionics
  • Postgres Learning Center
    • Webinars
      • Upcoming Webinars
      • Webinar Library
    • Whitepapers
      • Business Case for PostgreSQL Support
      • AlwaysOn Postgres
      • PostgreSQL with High Availability
      • Security Best Practices
      • BDR
    • Blog
    • Training
      • Course Catalogue
    • Case Studies
      • Performance Tuning
        • BenchPrep
        • tastyworks
      • Distributed Clusters
        • ClickUp
        • European Space Agency (ESA)
        • Telefónica del Sur
        • Animal Logic
      • Database Administration
        • Agilis Systems
      • Professional Training
        • Met Office
        • London & Partners
      • Database Upgrades
        • Alfred Wegener Institute (AWI)
      • Database Migration
        • International Game Technology (IGT)
        • Healthcare Software Solutions (HSS)
        • Navionics
    • Books
      • PostgreSQL 11 Administration Cookbook
      • PostgreSQL 10 Administration Cookbook
      • PostgreSQL High Availability Cookbook – 2nd Edition
      • PostgreSQL 9 Administration Cookbook – 3rd Edition
      • PostgreSQL Server Programming Cookbook – 2nd Edition
      • PostgreSQL 9 Cookbook – Chinese Edition
    • Videos
    • Events
    • PostgreSQL
      • PostgreSQL – History
      • Who uses PostgreSQL?
      • PostgreSQL FAQ
      • PostgreSQL vs MySQL
      • The Business Case for PostgreSQL
      • Security Information
      • Documentation
  • About Us
    • About 2ndQuadrant
    • What Does “2ndQuadrant” Mean?
    • 2ndQuadrant’s Passion for PostgreSQL
    • News
    • Careers
    • Team Profile
  • Blog
  • Menu Menu
You are here: Home1 / Blog2 / Umair's PlanetPostgreSQL3 / Using Java arrays to insert, retrieve, & update PostgreSQL arrays
Umair Shahid

Using Java arrays to insert, retrieve, & update PostgreSQL arrays

May 17, 2016/0 Comments/in Umair's PlanetPostgreSQL /by Umair Shahid

Arrays are a powerful programming feature frequently used by developers, both in Java and in PL/pgSQL. Interfaces can potentially become tricky, however, when the two try and talk to each other. This section explores how you can write simple code that uses the java.sql.Array Interface to insert, retrieve, & update arrays in PostgreSQL.

To illustrate the functionality, let’s set up a simple table that stores country names in one column as TEXT and a list of some of the country’s cities in the second column as a TEXT ARRAY.

CREATE TABLE city_example (
country TEXT, 
cities TEXT[]
);

Now we will use the JDBC interface to insert data into this table, retrieve it, and update it.

Inserting ARRAYs

Anyone familiar with Java has used arrays in one form or the other. Before these arrays can be stored in PostgreSQL, however, they need to be mapped to the Interface provided in the java.sql package … Array.

The JDBC driver provides functions that map Java arrays to their corresponding PostgreSQL arrays. Mapping is database-specific and is defined in PostgreSQL JDBC’s org.postgresql.jdbc2.TypeInfoCache file. It is important to note that mapping is case sensitive. As an example, “INTEGER” is not the same as “integer”.

In the code that follows, function createArrayOf of the Connection Interface is used to convert Java String arrays to PostgreSQL TEXT Arrays before insertion.

try {
 
 String[] usa = {"New York", "Chicago", "San Francisco"};
 String[] canada = {"Montreal", "Toronto", "Vancouver"};
 String[] uk = {"London", "Birmingham", "Oxford"};

 /*
 Convert String[] to java.sql.Array using JDBC API
 */
 Array arrayUSA = conn.createArrayOf("text", usa);
 Array arrayCanada = conn.createArrayOf("text", canada);
 Array arrayUK = conn.createArrayOf("text", uk);
 String sql = "INSERT INTO city_example VALUES (?, ?)";
 PreparedStatement pstmt = conn.prepareStatement(sql);
 
 pstmt.setString(1, "USA");
 pstmt.setArray(2, arrayUSA);
 pstmt.executeUpdate();
 
 pstmt.setString(1, "Canada");
 pstmt.setArray(2, arrayCanada);
 pstmt.executeUpdate();
 pstmt.setString(1, "UK");
 pstmt.setArray(2, arrayUK);
 pstmt.executeUpdate();
 
 conn.commit();
} catch (Exception e) {
 
 System.out.println(e.getMessage());
 e.printStackTrace();
}

Please note that the data type specified in Connection.createArrayOf has to be a PostgreSQL type, not java.sql.Types. The JDBC driver looks up the data type at runtime to create the java.sql.Array object.

This code, when executed, results in the following data in the city_example table:

select * from city_example ; 
 country | cities 
---------+--------------------------------------
 USA     | {"New York",Chicago,"San Francisco"}
 Canada  | {Montreal,Toronto,Vancouver}
 UK      | {London,Birmingham,Oxford}
(3 rows)

Retrieving ARRAYs

Process of retrieving arrays is the exact reverse of inserting them. In the example below, first step is to get a ResultSet with the required data and second step is to convert PostgreSQL TEXT Arrays to Java String arrays.

try { 
 
 String sql = "SELECT * FROM city_example";
 PreparedStatement ps = conn.prepareStatement(sql);
 ResultSet rs = ps.executeQuery();
 
 while(rs.next()) {
 
 System.out.println("Country: " + rs.getString(1));
 System.out.println("---------------");
 
 Array cities = rs.getArray(2);
 String[] str_cities = (String[])cities.getArray();
 
 for (int i=0; i<str_cities.length; i++) {
 System.out.println(str_cities[i]);
 }
System.out.println("");
}
 
} catch (Exception e) {
 
 System.out.println(e.getMessage());
 e.printStackTrace();
}

For the above code, output to stdout is:

Country: USA
---------------
New York
Chicago
San Francisco
Country: Canada
---------------
Montreal
Toronto
Vancouver
Country: UK
---------------
London
Birmingham
Oxford

Updating ARRAYs

Process of updating arrays in PostgreSQL is pretty close to that of inserting them. In the code below, a new set of USA cities is declared as a Java String array, which is then converted to a PostgreSQL TEXT array before updating the existing row.

try {
 
 String[] usa = {"New York", "Chicago", "San Francisco", "Miami", "Seattle"};
 Array arrayUSA = conn.createArrayOf("text", usa);
 
 String sql = "UPDATE city_example SET cities = ? WHERE country = 'USA'";
 PreparedStatement pstmt = conn.prepareStatement(sql);
 
 pstmt.setArray(1, arrayUSA);
 pstmt.executeUpdate();
 
 conn.commit();
 
} catch (Exception e) {
 
 System.out.println(e.getMessage());
 e.printStackTrace();
}

After execution of this code, the database table looks as follows:

select * from city_example ;
 country | cities 
---------+----------------------------------------------------
 Canada  | {Montreal,Toronto,Vancouver}
 UK      | {London,Birmingham,Oxford}
 USA     | {"New York",Chicago,"San Francisco",Miami,Seattle}
(3 rows)
Share this entry
  • Share on Facebook
  • Share on Twitter
  • Share on WhatsApp
  • Share on LinkedIn
0 replies

Leave a Reply

Want to join the discussion?
Feel free to contribute!

Leave a Reply Cancel reply

Your email address will not be published. Required fields are marked *

Search

Get in touch with us!

Recent Posts

  • Random Data December 3, 2020
  • Webinar: COMMIT Without Fear – The Beauty of CAMO [Follow Up] November 13, 2020
  • Full-text search since PostgreSQL 8.3 November 5, 2020
  • Random numbers November 3, 2020
  • Webinar: Best Practices for Bulk Data Loading in PostgreSQL [Follow Up] November 2, 2020

Featured External Blogs

Tomas Vondra's Blog

Our Bloggers

  • Simon Riggs
  • Alvaro Herrera
  • Andrew Dunstan
  • Craig Ringer
  • Francesco Canovai
  • Gabriele Bartolini
  • Giulio Calacoci
  • Ian Barwick
  • Marco Nenciarini
  • Mark Wong
  • Pavan Deolasee
  • Petr Jelinek
  • Shaun Thomas
  • Tomas Vondra
  • Umair Shahid

PostgreSQL Cloud

2QLovesPG 2UDA 9.6 backup Barman BDR Business Continuity community conference database DBA development devops disaster recovery greenplum Hot Standby JSON JSONB logical replication monitoring OmniDB open source Orange performance PG12 pgbarman pglogical PG Phriday postgres Postgres-BDR postgres-xl PostgreSQL PostgreSQL 9.6 PostgreSQL10 PostgreSQL11 PostgreSQL 11 PostgreSQL 11 New Features postgresql repmgr Recovery replication security sql wal webinar webinars

Support & Services

24/7 Production Support

Developer Support

Remote DBA for PostgreSQL

PostgreSQL Database Monitoring

PostgreSQL Health Check

PostgreSQL Performance Tuning

Database Security Audit

Upgrade PostgreSQL

PostgreSQL Migration Assessment

Migrate from Oracle to PostgreSQL

Products

HA Postgres Clusters

Postgres-BDR®

2ndQPostgres

pglogical

repmgr

Barman

Postgres Cloud Manager

SQL Firewall

Postgres-XL

OmniDB

Postgres Installer

2UDA

Postgres Learning Center

Introducing Postgres

Blog

Webinars

Books

Videos

Training

Case Studies

Events

About Us

About 2ndQuadrant

What does 2ndQuadrant Mean?

News

Careers 

Team Profile

© 2ndQuadrant Ltd. All rights reserved. | Privacy Policy
  • Twitter
  • LinkedIn
  • Facebook
  • Youtube
  • Mail
PGLogical 1.1 packages for PostgreSQL 9.6beta1 How Postgres-XL is tested
Scroll to top
×