Transactions with MariaDB Connector/C++

Overview

Developers can use MariaDB Connector/C++ to perform basic DML (Data Manipulation Language) operations inside a transaction with MariaDB database products.

Auto-Commit Behavior

By default, MariaDB Connector/C++ enables auto-commit. When auto-commit is enabled, each SQL statement is executed in its own transaction.

Confirm that auto-commit is enabled by calling sql::Connection::getAutoCommit():

bool isAutoCommit = conn->getAutoCommit();

Multi-Statement Transactions

MariaDB Connector/C++ supports multi-statement transactions when auto-commit is disabled.

Disable auto-commit by calling sql::Connection::setAutoCommit():

conn->setAutoCommit(false);

When auto-commit is disabled, a new transaction is automatically started when the current transaction is manually committed or rolled back. This means your application does not need to manually start each new transaction with START TRANSACTIONSTART TRANSACTION or BEGIN.

The transaction can be manually managed by performing the following operations:

Code Example: DML in Transaction

UPDATEUPDATE, INSERTINSERT, and DELETEDELETE are DML (Data Manipulation Language) operations that modify data in a table.

The following code demonstrates how to execute UPDATEUPDATE on the example table within a transaction with auto-commit disabled.

To insert or delete data, replace the UPDATEUPDATE statement in the code example with an INSERTINSERT or DELETEDELETE statement:

// Includes
#include <iostream>
#include <mariadb/conncpp.hpp>

void updateContact(std::shared_ptr<sql::PreparedStatement> &stmnt,
                   sql::SQLString first_name,
                   sql::SQLString email)
{
   try {
      // Bind variables to prepared statement parameters
      // Note that the index starts at 1--not 0
      stmnt->setString(1, email);
      stmnt->setString(2, first_name);

      // Execute Statement
      stmnt->executeUpdate();
   }

   // Catch Exception
   catch (sql::SQLException &e) {
      std::cerr << "Error updating contact: "
         << e.what() << std::endl;
   }
}

// Main Process
int main(int argc, char **argv)
{
   try {
      // Instantiate Driver
      sql::Driver* driver = sql::mariadb::get_driver_instance();

      // Configure Connection
      // The URL or TCP connection string format is
      // ``jdbc:mariadb://host:port/database``.
      sql::SQLString url("jdbc:mariadb://192.0.2.1:3306/test");

      // Use a properties map for the other connection options
      sql::Properties properties({
            {"user", "db_user"},
            {"password", "db_user_password"},
         });

      // Establish Connection
      // Use a smart pointer for extra safety
      std::unique_ptr<sql::Connection> conn(driver->connect(url, properties));

      // Use Connection to update contacts with a transaction
      try {
         // Disabling ``auto-commit`` mode automatically starts a new user managed transaction.
         conn->setAutoCommit(false);

         // Create a PreparedStatement
         // Use a smart pointer for extra safety
         std::shared_ptr<sql::PreparedStatement> stmnt(conn->prepareStatement(
                  "UPDATE test.contacts SET email=? WHERE first_name = ?"
               )
            );

         std::string contacts[3][2] = {
               { "John", "johnsmith@example.com" },
               { "Jon", "jonsmith@example.com" },
               { "Johnny", "johnnysmith@example.com" }
            };

         for (int row { 0 }; row < 3; ++row) {
            updateContact(stmnt, contacts[row][0], contacts[row][1]);
         }

         // Commit the transaction
         conn->commit();
      }
      catch (sql::SQLException &e) {
         std::cerr << "Error updating contact with a transaction: "
            << e.what() << std::endl;

         // Rollback the transaction
         conn->rollback();
      }

      // Close Connection
      conn->close();
   }
   catch (sql::SQLException &e) {
      std::cerr << "SQL exception in the database: "
         << e.what() << std::endl;

      // Exit (Failed)
      return 1;
   }

   // Exit (Success)
   return 0;
}
// Includes
#include <iostream>
#include <mariadb/conncpp.hpp>

void updateContact(std::shared_ptr<sql::PreparedStatement> &stmnt,
                   sql::SQLString first_name,
                   sql::SQLString email)
{
   try {
      // Bind variables to prepared statement parameters
      // Note that the index starts at 1--not 0
      stmnt->setString(1, email);
      stmnt->setString(2, first_name);

      // Execute Statement
      stmnt->executeUpdate();
   }

   // Catch Exception
   catch (sql::SQLException &e) {
      std::cerr << "Error updating contact: "
         << e.what() << std::endl;
   }
}

// Main Process
int main(int argc, char **argv)
{
   try {
      // Instantiate Driver
      sql::Driver* driver = sql::mariadb::get_driver_instance();

      // Configure Connection, including initial database name "test":
      sql::SQLString url("jdbc:mariadb://example.skysql.net:5009/test");

      // Use a properties map for the other connection options
      sql::Properties properties({
            {"user", "db_user"},
            {"password", "db_user_password"},
            {"autocommit", false},
            {"useTls", true},
            {"tlsCert", "classpath:static/skysql_chain.pem"},
         });

      // Establish Connection
      // Use a smart pointer for extra safety
      std::unique_ptr<sql::Connection> conn(driver->connect(url, properties));

      // Use Connection to update contacts with a transaction
      try {
         // Disabling ``auto-commit`` mode automatically starts a new user managed transaction.
         conn->setAutoCommit(false);

         // Create a PreparedStatement
         // Use a smart pointer for extra safety
         std::shared_ptr<sql::PreparedStatement> stmnt(conn->prepareStatement(
                  "UPDATE test.contacts SET email=? WHERE first_name = ?"
               )
            );

         std::string contacts[3][2] = {
               { "John", "johnsmith@example.com" },
               { "Jon", "jonsmith@example.com" },
               { "Johnny", "johnnysmith@example.com" }
            };

         for (int row { 0 }; row < 3; ++row) {
            updateContact(stmnt, contacts[row][0], contacts[row][1]);
         }

         // Commit the transaction
         conn->commit();
      }
      catch (sql::SQLException &e) {
         std::cerr << "Error updating contact with a transaction: "
            << e.what() << std::endl;

         // Rollback the transaction
         conn->rollback();
      }

      // Close Connection
      conn->close();
   }
   catch (sql::SQLException &e) {
      std::cerr << "SQL exception in the database: "
         << e.what() << std::endl;

      // Exit (Failed)
      return 1;
   }

   // Exit (Success)
   return 0;
}

The following query confirms the UPDATEUPDATE of the example table:

SELECT * from test.contacts;
+----+------------+-----------+-------------------------+
| id | first_name | last_name | email                   |
+----+------------+-----------+-------------------------+
|  1 | John       | Smith     | johnsmith@example.com   |
+----+------------+-----------+-------------------------+
|  2 | Jon        | Smith     | jonsmith@example.com    |
+----+------------+-----------+-------------------------+
|  3 | Johnny     | Smith     | johnnysmith@example.com |
+----+------------+-----------+-------------------------+