Build a Simple CRUD Go App with CockroachDB and the Go pgx Driver

This tutorial shows you how build a simple CRUD Go application with CockroachDB and the Go pgx driver.

Step 1. Start CockroachDB

Create a free cluster

  1. If you haven't already, sign up for a CockroachCloud account.
  2. Log in to your CockroachCloud account.
  3. On the Clusters page, click Create Cluster.
  4. On the Create your cluster page, select CockroachCloud Free.

    Note:

    This cluster will be free forever.

  5. (Optional) Select a cloud provider (GCP or AWS) in the Additional configuration section.

  6. (Optional) Select a region in the Additional configuration section. For optimal performance, select the cloud provider region closest to the region in which you are running your application.

  7. Click Create your free cluster.

Your cluster will be created in approximately 20-30 seconds.

Set up your cluster connection

  1. Navigate to the cluster's SQL Users page, and create a new user, with a new password.

  2. Navigate to the Cluster Overview page, select Connect, and, under the Connection String tab, download the cluster certificate.

  3. Take note of the connection string provided. You'll use it to connect to the database later in this tutorial.

  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.

  3. Take note of the (sql/unix) 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
    

    You'll use this connection string to connect to the database later in this tutorial.

Step 2. Get the code

Clone the code's GitHub repo:

icon/buttons/copy
$ git clone https://github.com/cockroachlabs/example-app-go-pgx/

The project has the following directory structure:

├── README.md
├── dbinit.sql
└── main.go

The dbinit.sql file initializes the database schema that the application uses:

icon/buttons/copy
SET sql_safe_updates = FALSE;

USE defaultdb;
DROP DATABASE IF EXISTS bank CASCADE;
CREATE DATABASE IF NOT EXISTS bank;

USE bank;

CREATE TABLE accounts (
    id UUID PRIMARY KEY,
    balance INT8
);

The main.go file contains the code for INSERT, SELECT, UPDATE, and DELETE SQL operations. The file also executes the main method of the program.

icon/buttons/copy
package main

import (
    "bufio"
    "context"
    "log"
    "os"
    "os/exec"

    "github.com/cockroachdb/cockroach-go/v2/crdb/crdbpgx"
    "github.com/google/uuid"
    "github.com/jackc/pgx/v4"
)

func insertRows(ctx context.Context, tx pgx.Tx, accts [4]uuid.UUID) error {
    // Insert four rows into the "accounts" table.
    log.Println("Creating new rows...")
    if _, err := tx.Exec(ctx,
        "INSERT INTO accounts (id, balance) VALUES ($1, $2), ($3, $4), ($5, $6), ($7, $8)", accts[0], 250, accts[1], 100, accts[2], 500, accts[3], 300); err != nil {
        return err
    }
    return nil
}

func printBalances(conn *pgx.Conn) error {
    rows, err := conn.Query(context.Background(), "SELECT id, balance FROM accounts")
    if err != nil {
        log.Fatal(err)
    }
    defer rows.Close()
    for rows.Next() {
        var id uuid.UUID
        var balance int
        if err := rows.Scan(&id, &balance); err != nil {
            log.Fatal(err)
        }
        log.Printf("%s: %d\n", id, balance)
    }
    return nil
}

func transferFunds(ctx context.Context, tx pgx.Tx, from uuid.UUID, to uuid.UUID, amount int) error {
    // Read the balance.
    var fromBalance int
    if err := tx.QueryRow(ctx,
        "SELECT balance FROM accounts WHERE id = $1", from).Scan(&fromBalance); err != nil {
        return err
    }

    if fromBalance < amount {
        log.Println("insufficient funds")
    }

    // Perform the transfer.
    log.Printf("Transferring funds from account with ID %s to account with ID %s...", from, to)
    if _, err := tx.Exec(ctx,
        "UPDATE accounts SET balance = balance - $1 WHERE id = $2", amount, from); err != nil {
        return err
    }
    if _, err := tx.Exec(ctx,
        "UPDATE accounts SET balance = balance + $1 WHERE id = $2", amount, to); err != nil {
        return err
    }
    return nil
}

func deleteRows(ctx context.Context, tx pgx.Tx, one uuid.UUID, two uuid.UUID) error {
    // Delete two rows into the "accounts" table.
    log.Printf("Deleting rows with IDs %s and %s...", one, two)
    if _, err := tx.Exec(ctx,
        "DELETE FROM accounts WHERE id IN ($1, $2)", one, two); err != nil {
        return err
    }
    return nil
}

func main() {
    // Read in connection string
    scanner := bufio.NewScanner(os.Stdin)
    log.Println("Enter a connection string: ")
    scanner.Scan()
    connstring := os.ExpandEnv(scanner.Text())

    // Initialize the database with the SQL file
    cmd := exec.Command("cockroach", "sql", "--url", connstring, "-f", "dbinit.sql")
    log.Println("Initializing bank database...")
    err := cmd.Run()
    if err != nil {
        log.Fatal("error initializing the database: ", err)
    } else {
        log.Println("bank database initialized.")
    }

    // Connect to the "bank" database
    config, err := pgx.ParseConfig(connstring)
    config.Database = "bank"
    if err != nil {
        log.Fatal("error configuring the database: ", err)
    }
    conn, err := pgx.ConnectConfig(context.Background(), config)
    if err != nil {
        log.Fatal("error connecting to the database: ", err)
    }
    defer conn.Close(context.Background())

    // Insert initial rows
    var accounts [4]uuid.UUID
    for i := 0; i < len(accounts); i++ {
        accounts[i] = uuid.New()
    }

    err = crdbpgx.ExecuteTx(context.Background(), conn, pgx.TxOptions{}, func(tx pgx.Tx) error {
        return insertRows(context.Background(), tx, accounts)
    })
    if err == nil {
        log.Println("New rows created.")
    } else {
        log.Fatal("error: ", err)
    }

    // Print out the balances
    log.Println("Initial balances:")
    printBalances(conn)

    // Run a transfer
    err = crdbpgx.ExecuteTx(context.Background(), conn, pgx.TxOptions{}, func(tx pgx.Tx) error {
        return transferFunds(context.Background(), tx, accounts[2], accounts[1], 100)
    })
    if err == nil {
        log.Println("Transfer successful.")
    } else {
        log.Fatal("error: ", err)
    }

    // Print out the balances
    log.Println("Balances after transfer:")
    printBalances(conn)

    // Delete rows
    err = crdbpgx.ExecuteTx(context.Background(), conn, pgx.TxOptions{}, func(tx pgx.Tx) error {
        return deleteRows(context.Background(), tx, accounts[0], accounts[1])
    })
    if err == nil {
        log.Println("Rows deleted.")
    } else {
        log.Fatal("error: ", err)
    }

    // Print out the balances
    log.Println("Balances after deletion:")
    printBalances(conn)
}

Note:

CockroachDB may require the client to retry a transaction in the case of read/write contention. The CockroachDB Go client includes a generic retry function (ExecuteTx()) that runs inside a transaction and retries it as needed. The code sample shows how you can use this function to wrap SQL statements.

Step 3. Run the code

Initialize the module:

icon/buttons/copy
$ go mod init basic-sample && go mod tidy

Then run the code:

icon/buttons/copy
$ go run main.go

The program will prompt you for a connection string to the database:

Enter a connection string:

Enter the (sql/unix) connection URL provided in the demo cluster's SQL shell welcome text.

Enter the connection string provided in the Connection info window of the CockroachCloud Console.

Note:

You need to provide a SQL user password in order to securely connect to a CockroachCloud cluster. The connection string should have a placeholder for the password (<ENTER-PASSWORD>).

The output should look similar to the following:

2021/07/20 14:48:01 Initializing bank database...
2021/07/20 14:48:02 bank database initialized.
2021/07/20 14:48:02 Creating new rows...
2021/07/20 14:48:02 New rows created.
2021/07/20 14:48:02 Initial balances:
2021/07/20 14:48:02 3a936990-a0c9-45bf-bc24-92e10d91dca9: 300
2021/07/20 14:48:02 8d1849dd-9222-4b12-a4ff-94e583b544a8: 250
2021/07/20 14:48:02 c6ae8917-d24e-4115-b719-f663dbfb9ffb: 500
2021/07/20 14:48:02 d0ce1f5c-e468-4899-8590-2bb6076247f2: 100
2021/07/20 14:48:02 Transferring funds from account with ID c6ae8917-d24e-4115-b719-f663dbfb9ffb to account with ID d0ce1f5c-e468-4899-8590-2bb6076247f2...
2021/07/20 14:48:02 Transfer successful.
2021/07/20 14:48:02 Balances after transfer:
2021/07/20 14:48:02 3a936990-a0c9-45bf-bc24-92e10d91dca9: 300
2021/07/20 14:48:02 8d1849dd-9222-4b12-a4ff-94e583b544a8: 250
2021/07/20 14:48:02 c6ae8917-d24e-4115-b719-f663dbfb9ffb: 400
2021/07/20 14:48:02 d0ce1f5c-e468-4899-8590-2bb6076247f2: 200
2021/07/20 14:48:02 Deleting rows with IDs 8d1849dd-9222-4b12-a4ff-94e583b544a8 and d0ce1f5c-e468-4899-8590-2bb6076247f2...
2021/07/20 14:48:02 Rows deleted.
2021/07/20 14:48:02 Balances after deletion:
2021/07/20 14:48:02 3a936990-a0c9-45bf-bc24-92e10d91dca9: 300
2021/07/20 14:48:02 c6ae8917-d24e-4115-b719-f663dbfb9ffb: 400

As shown in the output, the code does the following:

  • Initializes the bank database with the accounts table, using the dbinit.sql file.
  • Inserts some rows into the accounts table.
  • Reads values from the table.
  • Updates values in the table.
  • Deletes values from the table.

To verify that the SQL statements were executed, run the following query from inside the SQL shell:

icon/buttons/copy
> USE bank;
icon/buttons/copy
> SELECT id, balance FROM accounts;

The output should look similar to the following:

                   id                  | balance
---------------------------------------+----------
  3a936990-a0c9-45bf-bc24-92e10d91dca9 |     300
  c6ae8917-d24e-4115-b719-f663dbfb9ffb |     400
(2 rows)

What's next?

Read more about using the Go pgx driver.

You might also be interested in the following pages:

YesYes NoNo