This tutorial shows you how build a simple Java application with CockroachDB and the Hibernate ORM.

Note:

We recommend using Java versions 8+ with CockroachDB.

Tip:

For a sample app and tutorial that uses Spring Data JPA (Hibernate) and CockroachDB, see Build a Spring App with CockroachDB and JPA.

For another use of Hibernate with CockroachDB, see our examples-orms repository.

Step 1. Start CockroachDB

  1. If you haven't already, download the CockroachDB binary.
  2. Run the cockroach demo command:

    copy
    icon/buttons/copy
    $ cockroach demo \
    --empty
    

    This starts a temporary, in-memory cluster and opens an interactive SQL shell to the cluster.

  3. Take note of the (sql/tcp) connection string in the SQL shell welcome text:

    # Connection parameters:
    #   (console) http://127.0.0.1:61009
    #   (sql)     postgres://root:admin@?host=%2Fvar%2Ffolders%2Fk1%2Fr048yqpd7_9337rgxm9vb_gw0000gn%2FT%2Fdemo255013852&port=26257
    #   (sql/tcp) postgres://root:admin@127.0.0.1:61011?sslmode=require    
    

    You will use it in your application code later.

Step 2. Create a database

  1. In the SQL shell, create the bank database that your application will use:

    copy
    icon/buttons/copy
    > CREATE DATABASE bank;
    
  2. Create a SQL user for your app:

    copy
    icon/buttons/copy
    > CREATE USER <username> WITH PASSWORD <password>;
    

    Take note of the username and password. You will use it in your application code later.

  3. Give the user the necessary permissions:

    copy
    icon/buttons/copy
    > GRANT ALL ON DATABASE bank TO <username>;
    

Step 3. Run the Java code

The sample code in this tutorial (Sample.java)uses Hibernate to map Java methods to SQL operations. The code performs the following operations, which roughly correspond to method calls in the Sample class:

  1. Creates an accounts table in the bank database as specified by the Account mapping class.
  2. Inserts rows into the table with the addAccounts() method.
  3. Transfers money from one account to another with the transferFunds() method.
  4. Prints out account balances before and after the transfer with the getAccountBalance() method.

In addition, the code shows a pattern for automatically handling transaction retries by wrapping transactions in a higher-order function named runTransaction(). It also includes a method for testing the retry handling logic (Sample.forceRetryLogic()), which will be run if you set the FORCE_RETRY variable to true.

It does all of the above using the practices we recommend for using Hibernate (and the underlying JDBC connection) with CockroachDB, which are listed in the Recommended Practices section below.

The contents of Sample.java:

copy
icon/buttons/copy
package com.cockroachlabs;

import java.io.Serializable;
import java.math.BigDecimal;
import java.util.Random;
import java.util.function.Function;
import javax.persistence.Column;
import javax.persistence.Entity;
import javax.persistence.Id;
import javax.persistence.Table;
import org.hibernate.JDBCException;
import org.hibernate.Session;
import org.hibernate.SessionFactory;
import org.hibernate.Transaction;
import org.hibernate.cfg.Configuration;

public class Sample implements Serializable {

    private static final Random RAND = new Random();
    private static final boolean FORCE_RETRY = false;
    private static final String RETRY_SQL_STATE = "40001";
    private static final int MAX_ATTEMPT_COUNT = 6;

    // Account is our model, which corresponds to the "accounts" database table.
    @Entity
    @Table(name = "accounts")
    public static class Account {

        @Id
        @Column(name = "id")
        public long id;

        public long getId() {
            return id;
        }

        @Column(name = "balance")
        public BigDecimal balance;

        public BigDecimal getBalance() {
            return balance;
        }

        public void setBalance(BigDecimal newBalance) {
            this.balance = newBalance;
        }

        // Convenience constructor.
        public Account(int id, int balance) {
            this.id = id;
            this.balance = BigDecimal.valueOf(balance);
        }

        // Hibernate needs a default (no-arg) constructor to create model objects.
        public Account() {
        }
    }

    private static Function<Session, BigDecimal> addAccounts() throws JDBCException {
        Function<Session, BigDecimal> f = s -> {
            BigDecimal rv = new BigDecimal(0);
            try {
                s.save(new Account(1, 1000));
                s.save(new Account(2, 250));
                s.save(new Account(3, 314159));
                rv = BigDecimal.valueOf(1);
                System.out.printf("APP: addAccounts() --> %.2f\n", rv);
            } catch (JDBCException e) {
                throw e;
            }
            return rv;
        };
        return f;
    }

    private static Function<Session, BigDecimal> transferFunds(long fromId, long toId, BigDecimal amount) throws JDBCException {
        Function<Session, BigDecimal> f = s -> {
            BigDecimal rv = new BigDecimal(0);
            try {
                Account fromAccount = (Account) s.get(Account.class, fromId);
                Account toAccount = (Account) s.get(Account.class, toId);
                if (!(amount.compareTo(fromAccount.getBalance()) > 0)) {
                    fromAccount.balance = fromAccount.balance.subtract(amount);
                    toAccount.balance = toAccount.balance.add(amount);
                    s.save(fromAccount);
                    s.save(toAccount);
                    rv = amount;
                    System.out.printf("APP: transferFunds(%d, %d, %.2f) --> %.2f\n", fromId, toId, amount, rv);
                }
            } catch (JDBCException e) {
                throw e;
            }
            return rv;
        };
        return f;
    }

    // Test our retry handling logic if FORCE_RETRY is true.  This
    // method is only used to test the retry logic.  It is not
    // intended for production code.
    private static Function<Session, BigDecimal> forceRetryLogic() throws JDBCException {
        Function<Session, BigDecimal> f = s -> {
            BigDecimal rv = new BigDecimal(-1);
            try {
                System.out.printf("APP: testRetryLogic: BEFORE EXCEPTION\n");
                s.createNativeQuery("SELECT crdb_internal.force_retry('1s')").executeUpdate();
            } catch (JDBCException e) {
                System.out.printf("APP: testRetryLogic: AFTER EXCEPTION\n");
                throw e;
            }
            return rv;
        };
        return f;
    }

    private static Function<Session, BigDecimal> getAccountBalance(long id) throws JDBCException {
        Function<Session, BigDecimal> f = s -> {
            BigDecimal balance;
            try {
                Account account = s.get(Account.class, id);
                balance = account.getBalance();
                System.out.printf("APP: getAccountBalance(%d) --> %.2f\n", id, balance);
            } catch (JDBCException e) {
                throw e;
            }
            return balance;
        };
        return f;
    }

    // Run SQL code in a way that automatically handles the
    // transaction retry logic so we don't have to duplicate it in
    // various places.
    private static BigDecimal runTransaction(Session session, Function<Session, BigDecimal> fn) {
        BigDecimal rv = new BigDecimal(0);
        int attemptCount = 0;

        while (attemptCount < MAX_ATTEMPT_COUNT) {
            attemptCount++;

            if (attemptCount > 1) {
                System.out.printf("APP: Entering retry loop again, iteration %d\n", attemptCount);
            }

            Transaction txn = session.beginTransaction();
            System.out.printf("APP: BEGIN;\n");

            if (attemptCount == MAX_ATTEMPT_COUNT) {
                String err = String.format("hit max of %s attempts, aborting", MAX_ATTEMPT_COUNT);
                throw new RuntimeException(err);
            }

            // This block is only used to test the retry logic.
            // It is not necessary in production code.  See also
            // the method 'testRetryLogic()'.
            if (FORCE_RETRY) {
                session.createNativeQuery("SELECT now()").list();
            }

            try {
                rv = fn.apply(session);
                if (!rv.equals(-1)) {
                    txn.commit();
                    System.out.printf("APP: COMMIT;\n");
                    break;
                }
            } catch (JDBCException e) {
                if (RETRY_SQL_STATE.equals(e.getSQLState())) {
                    // Since this is a transaction retry error, we
                    // roll back the transaction and sleep a little
                    // before trying again.  Each time through the
                    // loop we sleep for a little longer than the last
                    // time (A.K.A. exponential backoff).
                    System.out.printf("APP: retryable exception occurred:\n    sql state = [%s]\n    message = [%s]\n    retry counter = %s\n", e.getSQLState(), e.getMessage(), attemptCount);
                    System.out.printf("APP: ROLLBACK;\n");
                    txn.rollback();
                    int sleepMillis = (int) (Math.pow(2, attemptCount) * 100) + RAND.nextInt(100);
                    System.out.printf("APP: Hit 40001 transaction retry error, sleeping %s milliseconds\n", sleepMillis);
                    try {
                        Thread.sleep(sleepMillis);
                    } catch (InterruptedException ignored) {
                        // no-op
                    }
                    rv = BigDecimal.valueOf(-1);
                } else {
                    throw e;
                }
            }
        }
        return rv;
    }

    public static void main(String[] args) {
        // Create a SessionFactory based on our hibernate.cfg.xml configuration
        // file, which defines how to connect to the database.
        SessionFactory sessionFactory
                = new Configuration()
                        .configure("hibernate.cfg.xml")
                        .addAnnotatedClass(Account.class)
                        .buildSessionFactory();

        try (Session session = sessionFactory.openSession()) {
            long fromAccountId = 1;
            long toAccountId = 2;
            BigDecimal transferAmount = BigDecimal.valueOf(100);

            if (FORCE_RETRY) {
                System.out.printf("APP: About to test retry logic in 'runTransaction'\n");
                runTransaction(session, forceRetryLogic());
            } else {

                runTransaction(session, addAccounts());
                BigDecimal fromBalance = runTransaction(session, getAccountBalance(fromAccountId));
                BigDecimal toBalance = runTransaction(session, getAccountBalance(toAccountId));
                if (!fromBalance.equals(-1) && !toBalance.equals(-1)) {
                    // Success!
                    System.out.printf("APP: getAccountBalance(%d) --> %.2f\n", fromAccountId, fromBalance);
                    System.out.printf("APP: getAccountBalance(%d) --> %.2f\n", toAccountId, toBalance);
                }

                // Transfer $100 from account 1 to account 2
                BigDecimal transferResult = runTransaction(session, transferFunds(fromAccountId, toAccountId, transferAmount));
                if (!transferResult.equals(-1)) {
                    // Success!
                    System.out.printf("APP: transferFunds(%d, %d, %.2f) --> %.2f \n", fromAccountId, toAccountId, transferAmount, transferResult);

                    BigDecimal fromBalanceAfter = runTransaction(session, getAccountBalance(fromAccountId));
                    BigDecimal toBalanceAfter = runTransaction(session, getAccountBalance(toAccountId));
                    if (!fromBalanceAfter.equals(-1) && !toBalanceAfter.equals(-1)) {
                        // Success!
                        System.out.printf("APP: getAccountBalance(%d) --> %.2f\n", fromAccountId, fromBalanceAfter);
                        System.out.printf("APP: getAccountBalance(%d) --> %.2f\n", toAccountId, toBalanceAfter);
                    }
                }
            }
        } finally {
            sessionFactory.close();
        }
    }
}

To run it:

  1. Clone the hello-world-java-hibernate repo to your machine:

    copy
    icon/buttons/copy
    git clone https://github.com/cockroachlabs/hello-world-java-hibernate/
    
    Note:

    The version of the CockroachDB Hibernate dialect in hibernate.cfg.xml corresponds to a version of CockroachDB. For more information, see Install Client Drivers: Hibernate.

  2. Edit src/main/resources/hibernate.cfg.xml in a text editor.

    1. Modify the hibernate.connection.url property with the port number from the connection string above:

      copy
      icon/buttons/copy
      <property name="hibernate.connection.url">jdbc:postgresql://localhost:{port}/bank?ssl=true&amp;sslmode=require</property>
      

      Where {port} is the port number on which the CockroachDB demo cluster is listening.

    2. Set the hibernate.connection.username property to the username you created earlier.

    3. Set the hibernate.connection.password property to the user's password.

  3. Compile and run the code using gradlew, which will also download the dependencies.

    copy
    icon/buttons/copy
    $ ./gradlew run
    

Toward the end of the output, you should see:

APP: BEGIN;
APP: addAccounts() --> 1.00
APP: COMMIT;
APP: BEGIN;
APP: getAccountBalance(1) --> 1000.00
APP: COMMIT;
APP: BEGIN;
APP: getAccountBalance(2) --> 250.00
APP: COMMIT;
APP: getAccountBalance(1) --> 1000.00
APP: getAccountBalance(2) --> 250.00
APP: BEGIN;
APP: transferFunds(1, 2, 100.00) --> 100.00
APP: COMMIT;
APP: transferFunds(1, 2, 100.00) --> 100.00
APP: BEGIN;
APP: getAccountBalance(1) --> 900.00
APP: COMMIT;
APP: BEGIN;
APP: getAccountBalance(2) --> 350.00
APP: COMMIT;
APP: getAccountBalance(1) --> 900.00
APP: getAccountBalance(2) --> 350.00

To verify that the account balances were updated successfully, start the built-in SQL client:

copy
icon/buttons/copy
$ cockroach sql --certs-dir={certs_dir}

Where: - {certs_dir} is the path to the directory containing the certificates and keys you generated earlier.

To check the account balances, issue the following statement:

copy
icon/buttons/copy
SELECT id, balance FROM accounts;
id |  balance
-----+------------
 1 |    900.00
 2 |    350.00
 3 | 314159.00
(3 rows)

Use IMPORT to read in large data sets

If you are trying to get a large data set into CockroachDB all at once (a bulk import), avoid writing client-side code altogether and use the IMPORT statement instead. It is much faster and more efficient than making a series of INSERTs and UPDATEs. It bypasses the SQL layer altogether and writes directly to the storage layer of the database.

For more information about importing data from Postgres, see Migrate from Postgres.

For more information about importing data from MySQL, see Migrate from MySQL.

Use rewriteBatchedInserts for increased speed

We strongly recommend setting rewriteBatchedInserts=true; we have seen 2-3x performance improvements with it enabled. From the JDBC connection parameters documentation:

This will change batch inserts from insert into foo (col1, col2, col3) values (1,2,3) into insert into foo (col1, col2, col3) values (1,2,3), (4,5,6) this provides 2-3x performance improvement

Retrieve large data sets in chunks using cursors

CockroachDB now supports the Postgres wire-protocol cursors for implicit transactions and explicit transactions executed to completion. This means the PGJDBC driver can use this protocol to stream queries with large result sets. This is much faster than paginating through results in SQL using LIMIT .. OFFSET.

For instructions showing how to use cursors in your Java code, see Getting results based on a cursor from the PGJDBC documentation.

Note that interleaved execution (partial execution of multiple statements within the same connection and transaction) is not supported when Statement.setFetchSize() is used.

What's next?

Read more about using the Hibernate ORM, or check out a more realistic implementation of Hibernate with CockroachDB in our examples-orms repository.

You might also be interested in the following pages:



YesYes NoNo