0
0
mirror of https://github.com/rbock/sqlpp11.git synced 2024-11-15 12:29:41 +08:00

Connection pools documentation and example (#533)

* Add an example of using a connection pool.

* Add documentation about the connection pools. Expand the documentation about multi-threading issues.
This commit is contained in:
MeanSquaredError 2023-10-03 10:45:21 +03:00 committed by GitHub
parent a2d884dab6
commit 7f04435576
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
9 changed files with 277 additions and 5 deletions

111
docs/Connection-Pools.md Normal file
View File

@ -0,0 +1,111 @@
# Introduction
SQLPP11 has support for connection pools which are centralized caches of database connections. When you need a database connection, you can fetch one from the connection pool, use the connection to make SQL
queries and when you no longer need the connection object, destroy it, usually by letting it go out of scope. When a connection object is destroyed, the actual connection to the database server is not closed,
but put in a cache instead and next time when you need a database connection object, you will be handed one that reuses a cached connection. If there are no connections is the cache, then a new connection
will be created, wrapped in a connection object and handed to you.
## Creating connection pools
Each connector has its own connection pool class. Currently we have
* sqlpp::mysql::connection_pool
* sqlpp::postgresql::connection_pool
* sqlpp::sqlite3::connection_pool
The connection pool constructors accept two parameters
* Shared pointer to a configuration object. This is the same configuration as the one that you use when creating regular (non-pooled) database connections.
* An integer specifying the initial size of the connection cache. This cache size grows automatically when necessary, so this value is not very important as pretty much any small positive value will do. In our example below we use 5.
In this example we create a PostgreSQL connection pool:
```
auto config = std::make_shared<sqlpp::postgresql::connection_config>();
config->dbname = "my_database";
config->user = "my_user";
config->password = "my_password";
config->debug = true;
auto pool = sqlpp::postgresql::connection_pool{config, 5};
```
You can also create a pool object without a configuration and initialize it later.
```
auto pool = sqlpp::postgresql::connection_pool{}
....
....
....
auto config = std::make_shared<sqlpp::postgresql::connection_config>();
config->dbname = "my_database";
config->user = "my_user";
config->password = "my_password";
config->debug = true;
pool.initialize(config, 5);
```
## Getting connections from the connection pool
Once the connection pool object is established we can use the _get()_ method to fetch connections
```
auto db = pool.get();
for (row : db(select(....))) {
....
}
```
## Returning connections to the connection pool
We don't really need to do anything to return the connection to the pool. Once the connection object's destructor is called the connection is not really destroyed but instead is returned automatically to the connection
pool's cache. This means that we can use the connection pool in the following way
```
for (row : pool.get()(select(....))) {
....
}
```
In the above example we fetch a connection from the pool, use it to make an SQL query and then return the connection to the pool.
## Ensuring that connections handed out by the connection pool are valid
Connection pools handle out connections that are either newly created or fetched from the connection cache. For connections that are fetched from the cache an optional check can be made to ensure that the connection is still active.
If the cached connection is no longer active, then it is discarded and the user is handed a newly created connection.
The check type is specified as an optional parameter of the _get()_ method. Currently the following check types are supported:
* **sqlpp::connection_check::none** Don't check the connection
* **sqlpp::connection_check::passive** A passive check which does not send anything to the server but just checks if the server side has already closed their side of the connection. This check type is supported only for PostgreSQL, for the other connector types it is treated as _none_.
* **sqlpp::connection_check::ping** Send a dummy request to the server to check if the connection is still alive. For MySQL connections this check uses the `mysql_ping` library function. For the other connector types
this check sends `SELECT 1` to the server.
For example:
```
auto db = pool.get(sqlpp::connection_check::ping);
for (row : db(select(....))) {
....
}
```
## Working around connection thread-safety issues
Connection pools can be used to work around [thread-safety issues](Threads.md) by ensuring that no connection is used simultaneously by multiple threads.
### Getting a new connection for each request
One possible usage pattern is getting a new connection handle for each request. For example:
```
for (row : pool.get()(select(....))) {
....
}
pool.get()(insert_into(mytable)....)
pool.get()(remove_from(mytable)....)
```
This usage pattern works well provided that you don't use transactions. If you use transactions then you must make sure that the transaction object and all queries inside the transaction use the same database connection.
### Using one connection per thread
Another usage pattern that works around the multi-threading problems is keeping a connection handle in a global thread_local object. This global object is not a real connection, but a wrapper which lazily fetches a connection from the
thread pool the first time when it is used to execute a database query. The wrapper will expose all the relevant methods and will forward them to the real connection. This way each thread can use the global wrapper as a database
connection and the thread_local storage class specifier will make sure that each thread accesses its own database connection. You can see examples/connection_pool as an example of this usage pattern.

View File

@ -23,4 +23,5 @@ The following pages will tell you how to use it:
* [Transactions](Transactions.md) * [Transactions](Transactions.md)
* [Thread Safety](Threads.md) * [Thread Safety](Threads.md)
* [NULL](NULL.md) * [NULL](NULL.md)
* [Connection Pools](Connection-Pools.md)
* [New Features](New-Features.md) * [New Features](New-Features.md)

View File

@ -1,10 +1,19 @@
# Thread Safety # Thread Safety
sqlpp11 aspires to have no influence on thread safety itself, but offers sqlpp11 aspires to have no influence on thread safety itself, but offers
no particular guarantees (PRs welcome). no particular guarantees (PRs welcome). This means that in the general case
your program may have problems if it does one of the following
* Creates a connection in one thread and then uses it in another thread..
* Uses the same connection simultaneously in multiple threads.
The exact level of thread-safety depends on the underlying client library, for
example with MySQL, PostgreSQL and SQLite3 it is generally safe to create a
connection in one thread and then use it in another thread, but attempting to
use the same connection simultaneously in multiple threads causes crashes,
lock-ups and SQL errors.
The recommendation therefore is to **not share** connections between threads The recommendation therefore is to **not share** connections between threads
and to read about thread safety of the underlying database for more and to read about thread safety of the underlying database for more
information. information. You may also look into [Connection Pools](Connection-Pools.md)
as a way to make SQL queries simultaneously in multiple threads.

View File

@ -0,0 +1,48 @@
# Copyright (c) 2023, Vesselin Atanasov
# All rights reserved.
#
# Redistribution and use in source and binary forms, with or without modification,
# are permitted provided that the following conditions are met:
#
# Redistributions of source code must retain the above copyright notice, this
# list of conditions and the following disclaimer.
#
# Redistributions in binary form must reproduce the above copyright notice, this
# list of conditions and the following disclaimer in the documentation and/or
# other materials provided with the distribution.
#
# THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" AND
# ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED
# WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
# DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE FOR
# ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL DAMAGES
# (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR SERVICES;
# LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON
# ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT
# (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS
# SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
cmake_minimum_required(VERSION 3.14)
set (APP_NAME "connection_pool")
project ("${APP_NAME}" CXX)
set (CMAKE_CXX_STANDARD 11)
set (CMAKE_CXX_STANDARD_REQUIRED true)
set (CMAKE_CXX_EXTENSIONS false)
# Executable file and its build settings
add_executable ("${APP_NAME}")
target_include_directories ("${APP_NAME}" PRIVATE "${GEN_HEADERS_DIR}" "${PROJECT_SOURCE_DIR}/src")
# Linked libraries
find_package (Sqlpp11 REQUIRED COMPONENTS PostgreSQL)
target_link_libraries ("${APP_NAME}" PRIVATE sqlpp11::postgresql)
# Project sources
target_sources (
"${APP_NAME}" PRIVATE
"src/db_connection.h"
"src/db_connection.cpp"
"src/db_global.h"
"src/db_global.cpp"
"src/main.cpp"
)

View File

@ -0,0 +1,15 @@
#include <memory>
#include <db_connection.h>
db_connection::pq_conn& db_connection::fetch()
{
if (m_conn_ptr == nullptr)
{
m_conn_ptr = sqlpp::compat::make_unique<pq_conn>(m_pool.get());
}
return *m_conn_ptr;
}
db_connection::db_connection(sqlpp::postgresql::connection_pool& pool) : m_pool{pool}, m_conn_ptr{nullptr}
{
}

View File

@ -0,0 +1,31 @@
#pragma once
#include <sqlpp11/postgresql/postgresql.h>
class db_connection
{
private:
using pq_conn = sqlpp::postgresql::pooled_connection;
sqlpp::postgresql::connection_pool& m_pool;
// For C++17 or newer just use std::optional<pq_conn> m_conn;
std::unique_ptr<pq_conn> m_conn_ptr;
pq_conn& fetch();
public:
db_connection(sqlpp::postgresql::connection_pool& pool);
db_connection(const db_connection&) = delete;
db_connection(db_connection&&) = delete;
db_connection& operator=(const db_connection&) = delete;
db_connection& operator=(db_connection&&) = delete;
// Delegate any methods of sqlpp::postgresql::connection that you may need
template <typename T>
auto operator()(const T& t) -> decltype(fetch()(t))
{
return fetch()(t);
}
};

View File

@ -0,0 +1,12 @@
#include <db_connection.h>
#include <sqlpp11/postgresql/postgresql.h>
static sqlpp::postgresql::connection_pool g_db_pool{};
thread_local db_connection g_dbc{g_db_pool};
void db_global_init(std::shared_ptr<sqlpp::postgresql::connection_config> config)
{
g_db_pool.initialize(config, 5);
}

View File

@ -0,0 +1,7 @@
#pragma once
#include <db_connection.h>
extern thread_local db_connection g_dbc;
void db_global_init(std::shared_ptr<sqlpp::postgresql::connection_config> config);

View File

@ -0,0 +1,38 @@
#include <db_global.h>
#include <sqlpp11/postgresql/postgresql.h>
#include <sqlpp11/sqlpp11.h>
#include <memory>
#include <thread>
int main()
{
// Initialize the global connection variable
auto config = std::make_shared<sqlpp::postgresql::connection_config>();
config->dbname = "my_database";
config->user = "my_username";
config->password = "my_password";
config->debug = false;
db_global_init(config);
// Spawn 10 threads and make them send SQL queries in parallel
int num_threads = 10;
int num_queries = 5;
std::vector<std::thread> threads {};
for (int i = 0; i < num_threads; ++i)
{
threads.push_back(std::thread([&] () {
for (int j = 0; j < num_queries; ++j)
{
g_dbc(select (sqlpp::value (1).as(sqlpp::alias::a)));
}
}));
}
for (auto&& t : threads)
{
t.join();
}
return 0;
}