This tutorial shows you how build a simple Node.js application with CockroachDB using a PostgreSQL-compatible driver. We’ve tested and can recommend the Node.js pg driver, so that driver is featured here.

Before You Begin

Make sure you have already installed CockroachDB.

Step 1. Install the Node.js pg driver

To install the Node.js pg driver, run the following command:

$ npm install pg

Step 2. Start a cluster

For the purpose of this tutorial, you need only one CockroachDB node running in insecure mode:

# Start node 1:
$ cockroach start --background \
--store=hello-1

But as you might’ve seen in the Start a Local Cluster tutorial, it’s incredibly easy to start and join addition nodes, if you want to simulate a real cluster:

# Start node 2:
$ cockroach start --background \
--store=hello-2 \
--port=26258 \
--http-port=8081 \
--join=localhost:26257

# Start node 3:
$ cockroach start --background \
--store=hello-3 \
--port=26259 \
--http-port=8082 \
--join=localhost:26257

Step 3. Create a user

As the root user, use the cockroach user command to create a new user, maxroach.

$ cockroach user set maxroach

Step 4. Create a database and grant privileges

As the root user, use the built-in SQL client to create a bank database.

$ cockroach sql -e 'CREATE DATABASE bank'

Then grant privileges to the maxroach user

$ cockroach sql -e 'GRANT ALL ON DATABASE bank TO maxroach'

Step 5. Run the Node.js code

Basic Statements

The following code connects as the maxroach user and executes some basic SQL statements, creating a table, inserting rows, and reading and printing the rows.

Copy the code or download it directly.

var async = require('async');

// Require the driver.
var pg = require('pg');

// Connect to the "bank" database.
var config = {
  user: 'maxroach',
  host: 'localhost',
  database: 'bank',
  port: 26257
};

pg.connect(config, function (err, client, done) {
  // Closes communication with the database and exits.
  var finish = function () {
    done();
    process.exit();
  };

  if (err) {
    console.error('could not connect to cockroachdb', err);
    finish();
  }
  async.waterfall([
    function (next) {
      // Create the "accounts" table.
      client.query("CREATE TABLE IF NOT EXISTS accounts (id INT PRIMARY KEY, balance INT);", next);
    },
    function (next) {
      // Insert two rows into the "accounts" table.
      client.query("INSERT INTO accounts (id, balance) VALUES (1, 1000), (2, 250);", next);
    },
    function (results, next) {
      // Print out the balances.
      client.query('SELECT id, balance FROM accounts;', next);
    },
  ],
  function (err, results) {
    if (err) {
      console.error('error inserting into and selecting from accounts', err);
      finish();
    }

    console.log('Initial balances:');
    results.rows.forEach(function (row) {
      console.log(row);
    });

    finish();
  });
});

Transaction (with retry logic)

The following code again connects as the maxroach user but this time executes a batch of statements as an atomic transaction to transfer funds from one account to another, where all included statements are either committed or aborted.

Copy the code or download it directly.

Because the CockroachDB transaction model requires the client to initiate retries in the case of contention, CockroachDB provides a generic retry function that runs inside a transaction and retries it as needed. You can copy and paste the retry function from here into your code. For more details, see Transaction Retries.
var async = require('async');

// Require the driver.
var pg = require('pg');

// Connect to the cluster.
var config = {
  user: 'maxroach',
  host: 'localhost',
  database: 'bank',
  port: 26257
};

// Wrapper for a transaction.
// This automatically re-calls "op" with the client as an argument as
// long as the database server asks for the transaction to be retried.
function txnWrapper(client, op, next) {
  client.query('BEGIN; SAVEPOINT cockroach_restart', function (err) {
    if (err) {
      return next(err);
    }

    var released = false;
    async.doWhilst(function (done) {
      var handleError = function (err) {
        // If we got an error, see if it's a retryable one and, if so, restart.
        if (err.code === '40001') {
          // Signal the database that we'll retry.
          return client.query('ROLLBACK TO SAVEPOINT cockroach_restart', done);
        }
        // A non-retryable error; break out of the doWhilst with an error.
        return done(err);
      };

      // Attempt the work.
      op(client, function (err) {
        if (err) {
          return handleError(err);
        }

        // If we reach this point, release and commit.
        client.query('RELEASE SAVEPOINT cockroach_restart', function (err) {
          if (err) {
            return handleError(err);
          }
          released = true;
          return done();
        });
      });
    },
    function () {
      return !released;
    },
    function (err) {
      if (err) {
        client.query('ROLLBACK', function () {
          next(err);
        });
      } else {
        client.query('COMMIT', next);
      }
    });
  });
}

// The transaction we want to run.
function transferFunds(client, from, to, amount, next) {
  // Check the current balance.
  client.query('SELECT balance FROM accounts WHERE id = $1', [from], function (err, results) {
    if (err) {
      return next(err);
    } else if (results.rows.length === 0) {
      return next(new Error('account not found in table'));
    }

    var acctBal = results.rows[0].balance;
    if (acctBal >= amount) {
      // Perform the transfer.
      async.series([
        function (next) {
          // Subtract amount from account 1.
          client.query('UPDATE accounts SET balance = balance - $1 WHERE id = $2', [amount, from], next);
        },
        function (next) {
          // Add amount to account 2.
          client.query('UPDATE accounts SET balance = balance + $1 WHERE id = $2', [amount, to], next);
        },
      ], next);
    } else {
      next(new Error('insufficient funds'));
    }
  });
}

pg.connect(config, function (err, client, done) {
  // Closes communication with the database and exits.
  var finish = function () {
    done();
    process.exit();
  };

  if (err) {
    console.error('could not connect to cockroachdb', err);
    finish();
  }

  // Execute the transaction.
  txnWrapper(client,
  function (client, next) {
    transferFunds(client, 1, 2, 100, next);
  },
  function (err, results) {
    if (err) {
      console.error('error performing transaction', err);
      finish();
    }

    // Check account balances after the transaction.
    client.query('SELECT id, balance FROM accounts', function (err, results) {
      if (err) {
        console.error('error querying accounts', err);
        finish();
      }

      console.log('Balances after transfer:');
      results.rows.forEach(function (row) {
        console.log(row);
      });

      finish();
    });
  });
});

After running the code, to verify that funds were, in fact, transferred from one account to another, you can again use the built-in SQL client:

$ cockroach sql -e 'SELECT id, balance FROM accounts' --database=bank
+----+---------+
| id | balance |
+----+---------+
|  1 |     900 |
|  2 |     350 |
+----+---------+
(2 rows)

What’s Next?

Read more about using the Node.js pg driver.

You might also be interested in using a local cluster to explore the following core CockroachDB features:



Yes No