Connect to TiDB with mysql.js

TiDB is a MySQL-compatible database, and mysql.js driver is a pure Node.js JavaScript client implementing the MySQL protocol.

In this tutorial, you can learn how to use TiDB and mysql.js driver to accomplish the following tasks:

  • Set up your environment.
  • Connect to your TiDB cluster using mysql.js driver.
  • Build and run your application. Optionally, you can find sample code snippets for basic CRUD operations.

Prerequisites

To complete this tutorial, you need:

  • Node.js >= 16.x installed on your machine.
  • Git installed on your machine.
  • A TiDB cluster running.

If you don't have a TiDB cluster, you can create one as follows:

Run the sample app to connect to TiDB

This section demonstrates how to run the sample application code and connect to TiDB.

Step 1: Clone the sample app repository

Run the following commands in your terminal window to clone the sample code repository:

git clone https://github.com/tidb-samples/tidb-nodejs-mysqljs-quickstart.git cd tidb-nodejs-mysqljs-quickstart

Step 2: Install dependencies

Run the following command to install the required packages (including mysql and dotenv) for the sample app:

npm install
Install dependencies to existing project

For your existing project, run the following command to install the packages:

npm install mysql dotenv --save

Step 3: Configure connection information

Connect to your TiDB cluster depending on the TiDB deployment option you've selected.

  • TiDB Cloud Serverless
  • TiDB Cloud Dedicated
  • TiDB Self-Managed
  1. Navigate to the Clusters page, and then click the name of your target cluster to go to its overview page.

  2. Click Connect in the upper-right corner. A connection dialog is displayed.

  3. Ensure the configurations in the connection dialog match your operating environment.

    • Connection Type is set to Public.
    • Branch is set to main.
    • Connect With is set to General.
    • Operating System matches the operating system where you run the application.
  4. If you have not set a password yet, click Generate Password to generate a random password.

  5. Run the following command to copy .env.example and rename it to .env:

    cp .env.example .env
  6. Edit the .env file, set up the environment variables as follows, replace the corresponding placeholders {} with connection parameters on the connection dialog:

    TIDB_HOST={host} TIDB_PORT=4000 TIDB_USER={user} TIDB_PASSWORD={password} TIDB_DATABASE=test TIDB_ENABLE_SSL=true
  7. Save the .env file.

  1. Navigate to the Clusters page, and then click the name of your target cluster to go to its overview page.

  2. Click Connect in the upper-right corner. A connection dialog is displayed.

  3. In the connection dialog, select Public from the Connection Type drop-down list, and then click CA cert to download the CA certificate.

    If you have not configured the IP access list, click Configure IP Access List or follow the steps in Configure an IP Access List to configure it before your first connection.

    In addition to the Public connection type, TiDB Dedicated supports Private Endpoint and VPC Peering connection types. For more information, see Connect to Your TiDB Dedicated Cluster.

  4. Run the following command to copy .env.example and rename it to .env:

    cp .env.example .env
  5. Edit the .env file, set up the environment variables as follows, replace the corresponding placeholders {} with connection parameters on the connection dialog:

    TIDB_HOST={host} TIDB_PORT=4000 TIDB_USER={user} TIDB_PASSWORD={password} TIDB_DATABASE=test TIDB_ENABLE_SSL=true TIDB_CA_PATH={downloaded_ssl_ca_path}
  6. Save the .env file.

  1. Run the following command to copy .env.example and rename it to .env:

    cp .env.example .env
  2. Edit the .env file, replace the corresponding placeholders {} with connection parameters of your cluster. The example configuration is as follows:

    TIDB_HOST={host} TIDB_PORT=4000 TIDB_USER=root TIDB_PASSWORD={password} TIDB_DATABASE=test

    If you are running TiDB locally, the default host address is 127.0.0.1, and the password is empty.

  3. Save the .env file.

Step 4: Run the code and check the result

Run the following command to execute the sample code:

npm start

If the connection is successful, the console will output the version of the TiDB cluster as follows:

🔌 Connected to TiDB cluster! (TiDB version: 8.0.11-TiDB-v8.5.0) ⏳ Loading sample game data... ✅ Loaded sample game data. 🆕 Created a new player with ID 12. ℹ️ Got Player 12: Player { id: 12, coins: 100, goods: 100 } 🔢 Added 50 coins and 50 goods to player 12, updated 1 row. 🚮 Deleted 1 player data.

Sample code snippets

You can refer to the following sample code snippets to complete your own application development.

For complete sample code and how to run it, check out the tidb-samples/tidb-nodejs-mysqljs-quickstart repository.

Connect with connection options

The following code establishes a connection to TiDB with options defined in the environment variables:

// Step 1. Import the 'mysql' and 'dotenv' packages. import { createConnection } from "mysql"; import dotenv from "dotenv"; import * as fs from "fs"; // Step 2. Load environment variables from .env file to process.env. dotenv.config(); // Step 3. Create a connection to the TiDB cluster. const options = { host: process.env.TIDB_HOST || '127.0.0.1', port: process.env.TIDB_PORT || 4000, user: process.env.TIDB_USER || 'root', password: process.env.TIDB_PASSWORD || '', database: process.env.TIDB_DATABASE || 'test', ssl: process.env.TIDB_ENABLE_SSL === 'true' ? { minVersion: 'TLSv1.2', ca: process.env.TIDB_CA_PATH ? fs.readFileSync(process.env.TIDB_CA_PATH) : undefined } : null, } const conn = createConnection(options); // Step 4. Perform some SQL operations... // Step 5. Close the connection. conn.end();

Insert data

The following query creates a single Player record and returns the ID of the newly created record:

conn.query('INSERT INTO players (coins, goods) VALUES (?, ?);', [100, 100], (err, ok) => { if (err) { console.error(err); } else { console.log(ok.insertId); } });

For more information, refer to Insert data.

Query data

The following query returns a single Player record by ID 1:

conn.query('SELECT id, coins, goods FROM players WHERE id = ?;', [1], (err, rows) => { if (err) { console.error(err); } else { console.log(rows[0]); } });

For more information, refer to Query data.

Update data

The following query adds 50 coins and 50 goods to the Player with ID 1:

conn.query( 'UPDATE players SET coins = coins + ?, goods = goods + ? WHERE id = ?;', [50, 50, 1], (err, ok) => { if (err) { console.error(err); } else { console.log(ok.affectedRows); } } );

For more information, refer to Update data.

Delete data

The following query deletes the Player record with ID 1:

conn.query('DELETE FROM players WHERE id = ?;', [1], (err, ok) => { if (err) { reject(err); } else { resolve(ok.affectedRows); } });

For more information, refer to Delete data.

Useful notes

  • Using connection pools to manage database connections can reduce the performance overhead caused by frequently establishing and destroying connections.

  • To avoid SQL injection attacks, it is recommended to use Escaping query values before executing SQL.

  • Using ORM frameworks to improve development efficiency in scenarios without a number of complex SQL statements, such as: Sequelize, TypeORM, and Prisma.

  • It is recommended to enable the supportBigNumbers: true option when dealing with big numbers (BIGINT and DECIMAL columns) in the database.

Next steps

Need help?

Ask the community on Discord or Slack, or submit a support ticket.

Was this page helpful?