Build a Java App with CockroachDB and Hibernate

On this page Carat arrow pointing down

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

Choose whether to run a temporary local cluster or a free CockroachDB cluster on CockroachDB Serverless. The instructions below will adjust accordingly.

Create a free cluster

Note:

Organizations without billing information on file can only create one CockroachDB Basic cluster.

  1. If you haven't already, sign up for a CockroachDB Cloud account.
  2. Log in to your CockroachDB Cloud account.
  3. On the Clusters page, click Create cluster.
  4. On the Select a plan page, select Basic.
  5. On the Cloud & Regions page, select a cloud provider (GCP or AWS) in the Cloud provider section.
  6. In the Regions section, select a region for the cluster. Refer to CockroachDB Cloud Regions for the regions where CockroachDB Basic clusters can be deployed. To create a multi-region cluster, click Add region and select additional regions.
  7. Click Next: Capacity.
  8. On the Capacity page, select Start for free. Click Next: Finalize.
  9. On the Finalize page, click Create cluster.

    Your cluster will be created in a few seconds and the Create SQL user dialog will display.

Set up your cluster connection

Once your cluster is created, the Connect to cluster-name dialog displays. Use the information provided in the dialog to set up your cluster connection for the SQL user that was created by default:

  1. In your terminal, run the second command from the dialog to create a new certs directory on your local machine and download the CA certificate to that directory:

    icon/buttons/copy
    curl --create-dirs -o ~/.postgresql/root.crt -O https://cockroachlabs.cloud/clusters/{cluster-id}/cert
    

    Your cert file will be downloaded to ~/.postgresql/root.crt.

    icon/buttons/copy
    curl --create-dirs -o ~/.postgresql/root.crt -O https://cockroachlabs.cloud/clusters/{cluster-id}/cert
    

    Your cert file will be downloaded to ~/.postgresql/root.crt.

    icon/buttons/copy
    mkdir -p $env:appdata\.postgresql\; Invoke-WebRequest -Uri https://cockroachlabs.cloud/clusters/{cluster-id}/cert -OutFile $env:appdata\.postgresql\root.crt
    

    Your cert file will be downloaded to %APPDATA%/.postgresql/root.crt.

  2. Copy the connection string provided, which will be used in the next steps (and to connect to your cluster in the future).

    Warning:

    This connection string contains your password, which will be provided only once. If you forget your password, you can reset it by going to the SQL Users page for the cluster, found at https://cockroachlabs.cloud/cluster/<CLUSTER ID>/users.

    icon/buttons/copy
    cockroach sql --url 'postgresql://<username>:<password>@<cluster-host>:26257/defaultdb?sslmode=verify-full&sslrootcert='$HOME'/.postgresql/root.crt'
    

    icon/buttons/copy
    cockroach sql --url 'postgresql://<username>:<password>@<cluster-host>:26257/defaultdb?sslmode=verify-full&sslrootcert='$HOME'/.postgresql/root.crt'
    
    icon/buttons/copy
    cockroach sql --url "postgresql://<username>:<password>@<cluster-host>:26257/defaultdb?sslmode=verify-full&sslrootcert=$env:appdata/.postgresql/root.crt"
    

    Where:

    • <username> is the SQL user. By default, this is your CockroachDB Cloud account username.
    • <password> is the password for the SQL user. The password will be shown only once in the Connection info dialog after creating the cluster.
    • <cluster-hostname> is the hostname of your CockroachDB Cloud cluster.
    • <cluster-id> is a unique string used to identify your cluster when downloading the CA certificate. For example, 12a3bcde-4fa5-6789-1234-56bc7890d123.

    You can find these settings in the Connection parameters tab of the Connection info dialog.

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

    icon/buttons/copy
    $ cockroach demo \
    --no-example-database
    

    This starts a temporary, in-memory cluster and opens an interactive SQL shell to the cluster. Any changes to the database will not persist after the cluster is stopped.

    Note:

    If cockroach demo fails due to SSL authentication, make sure you have cleared any previously downloaded CA certificates from the directory ~/.postgresql.

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

    # Connection parameters:
    #   (webui)    http://127.0.0.1:8080/demologin?password=demo76950&username=demo
    #   (sql)      postgres://demo:demo76950@127.0.0.1:26257?sslmode=require
    #   (sql/unix) postgres://demo:demo76950@?host=%2Fvar%2Ffolders%2Fc8%2Fb_q93vjj0ybfz0fz0z8vy9zc0000gp%2FT%2Fdemo070856957&port=26257
    

Step 2. Create a database

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

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

    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:

    icon/buttons/copy
    > GRANT ALL ON DATABASE bank TO <username>;
    
  1. If you haven't already, download the CockroachDB binary.
  2. Start the built-in SQL shell using the connection string you got from the CockroachDB Cloud Console earlier:

    icon/buttons/copy
    $ cockroach sql \
    --url='postgres://<username>:<password>@<global host>:26257/<cluster_name>.defaultdb?sslmode=verify-full&sslrootcert=<certs_dir>/cc-ca.crt'
    

    In the connection string copied from the CockroachDB Cloud Console, your username, password and cluster name are pre-populated. Replace the <certs_dir> placeholder with the path to the certs directory that you created earlier.

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

    icon/buttons/copy
    > CREATE DATABASE bank;
    
  4. Exit the SQL shell:

    icon/buttons/copy
    > \q
    

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:

icon/buttons/copy
package com.cockroachlabs;

import java.io.Serializable;
import java.math.BigDecimal;
import java.util.Random;
import java.util.function.Function;
import jakarta.persistence.Column;
import jakarta.persistence.Entity;
import jakarta.persistence.Id;
import jakarta.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;

    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();
        }
    }
}

Get the code

Clone the example-app-java-hibernate repo to your machine:

icon/buttons/copy
git clone https://github.com/cockroachlabs/example-app-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.

Update the connection parameters

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:

    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.

  1. Modify the hibernate.connection.url property with the information from the connection string you copied earlier host, cluster and database name, and path to the SSL certificate:

icon/buttons/copy

  <property name="hibernate.connection.url">jdbc:postgresql://{globalhost}:26257/{cluster_name}.bank?sslmode=verify-full&amp;sslrootcert={path to the CA certificate}</property>

Where:

  • {username} and {password} specify the SQL username and password that you created earlier.
  • {globalhost} is the name of the Serverless host (e.g., free-tier.gcp-us-central1.cockroachlabs.cloud).
  • {path to the CA certificate} is the path to the cc-ca.crt file that you downloaded from the CockroachDB Cloud Console.
  • {cluster_name} is the name of your cluster.
Note:

If you are using the connection string that you copied from the Connection info modal, your username, password, hostname, and cluster name will be pre-populated.

Run the code

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

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:

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:

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

Generate PKCS8 keys for client authentication

You can pass the --also-generate-pkcs8-key flag to cockroach cert to generate a key in PKCS#8 format, which is the standard key encoding format in Java. For example, if you have the user max:

icon/buttons/copy
$ cockroach cert create-client max --certs-dir=certs --ca-key=my-safe-directory/ca.key --also-generate-pkcs8-key

The generated PKCS8 key will be named client.max.key.pk8.

Note:

CockroachDB Cloud does not yet support certificate-based user authentication.

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:


Yes No
On this page

Yes No