Connection Pooling

A connection pool is a standard technique used to maintain long running connections in memory for efficient re-use, as well as to provide management for the total number of connections an application might use simultaneously.

Particularly for server-side web applications, a connection pool is the standard way to maintain a “pool” of active database connections in memory which are reused across requests.

SQLAlchemy includes several connection pool implementations which integrate with the Engine. They can also be used directly for applications that want to add pooling to an otherwise plain DBAPI approach.

Connection Pool Configuration

The Engine returned by the create_engine() function in most cases has a QueuePool integrated, pre-configured with reasonable pooling defaults. If you’re reading this section only to learn how to enable pooling - congratulations! You’re already done.

The most common QueuePool tuning parameters can be passed directly to create_engine() as keyword arguments: pool_size, max_overflow, pool_recycle and pool_timeout. For example:

engine = create_engine('postgresql://me@localhost/mydb',
                       pool_size=20, max_overflow=0)

In the case of SQLite, the SingletonThreadPool or NullPool are selected by the dialect to provide greater compatibility with SQLite’s threading and locking model, as well as to provide a reasonable default behavior to SQLite “memory” databases, which maintain their entire dataset within the scope of a single connection.

All SQLAlchemy pool implementations have in common that none of them “pre create” connections - all implementations wait until first use before creating a connection. At that point, if no additional concurrent checkout requests for more connections are made, no additional connections are created. This is why it’s perfectly fine for create_engine() to default to using a QueuePool of size five without regard to whether or not the application really needs five connections queued up - the pool would only grow to that size if the application actually used five connections concurrently, in which case the usage of a small pool is an entirely appropriate default behavior.

Switching Pool Implementations

The usual way to use a different kind of pool with create_engine() is to use the poolclass argument. This argument accepts a class imported from the sqlalchemy.pool module, and handles the details of building the pool for you. Common options include specifying QueuePool with SQLite:

from sqlalchemy.pool import QueuePool
engine = create_engine('sqlite:///file.db', poolclass=QueuePool)

Disabling pooling using NullPool:

from sqlalchemy.pool import NullPool
engine = create_engine(
          'postgresql+psycopg2://scott:tiger@localhost/test',
          poolclass=NullPool)

Using a Custom Connection Function

See the section Custom DBAPI connect() arguments / on-connect routines for a rundown of the various connection customization routines.

Constructing a Pool

To use a Pool by itself, the creator function is the only argument that’s required and is passed first, followed by any additional options:

import sqlalchemy.pool as pool
import psycopg2

def getconn():
    c = psycopg2.connect(user='ed', host='127.0.0.1', dbname='test')
    return c

mypool = pool.QueuePool(getconn, max_overflow=10, pool_size=5)

DBAPI connections can then be procured from the pool using the Pool.connect() function. The return value of this method is a DBAPI connection that’s contained within a transparent proxy:

# get a connection
conn = mypool.connect()

# use it
cursor = conn.cursor()
cursor.execute("select foo")

The purpose of the transparent proxy is to intercept the close() call, such that instead of the DBAPI connection being closed, it is returned to the pool:

# "close" the connection.  Returns
# it to the pool.
conn.close()

The proxy also returns its contained DBAPI connection to the pool when it is garbage collected, though it’s not deterministic in Python that this occurs immediately (though it is typical with cPython).

The close() step also performs the important step of calling the rollback() method of the DBAPI connection. This is so that any existing transaction on the connection is removed, not only ensuring that no existing state remains on next usage, but also so that table and row locks are released as well as that any isolated data snapshots are removed. This behavior can be disabled using the reset_on_return option of Pool.

A particular pre-created Pool can be shared with one or more engines by passing it to the pool argument of create_engine():

e = create_engine('postgresql://', pool=mypool)

Pool Events

Connection pools support an event interface that allows hooks to execute upon first connect, upon each new connection, and upon checkout and checkin of connections. See PoolEvents for details.

Dealing with Disconnects

The connection pool has the ability to refresh individual connections as well as its entire set of connections, setting the previously pooled connections as “invalid”. A common use case is allow the connection pool to gracefully recover when the database server has been restarted, and all previously established connections are no longer functional. There are two approaches to this.

Disconnect Handling - Pessimistic

The pessimistic approach refers to emitting a test statement on the SQL connection at the start of each connection pool checkout, to test that the database connection is still viable. Typically, this is a simple statement like “SELECT 1”, but may also make use of some DBAPI-specific method to test the connection for liveness.

The approach adds a small bit of overhead to the connection checkout process, however is otherwise the most simple and reliable approach to completely eliminating database errors due to stale pooled connections. The calling application does not need to be concerned about organizing operations to be able to recover from stale connections checked out from the pool.

It is critical to note that the pre-ping approach does not accommodate for connections dropped in the middle of transactions or other SQL operations. If the database becomes unavailable while a transaction is in progress, the transaction will be lost and the database error will be raised. While the Connection object will detect a “disconnect” situation and recycle the connection as well as invalidate the rest of the connection pool when this condition occurs, the individual operation where the exception was raised will be lost, and it’s up to the application to either abandon the operation, or retry the whole transaction again.

Pessimistic testing of connections upon checkout is achievable by using the Pool.pre_ping argument, available from create_engine() via the create_engine.pool_pre_ping argument:

engine = create_engine("mysql+pymysql://user:pw@host/db", pool_pre_ping=True)

The “pre ping” feature will normally emit SQL equivalent to “SELECT 1” each time a connection is checked out from the pool; if an error is raised that is detected as a “disconnect” situation, the connection will be immediately recycled, and all other pooled connections older than the current time are invalidated, so that the next time they are checked out, they will also be recycled before use.

If the database is still not available when “pre ping” runs, then the initial connect will fail and the error for failure to connect will be propagated normally. In the uncommon situation that the database is available for connections, but is not able to respond to a “ping”, the “pre_ping” will try up to three times before giving up, propagating the database error last received.

Note

the “SELECT 1” emitted by “pre-ping” is invoked within the scope of the connection pool / dialect, using a very short codepath for minimal Python latency. As such, this statement is not logged in the SQL echo output, and will not show up in SQLAlchemy’s engine logging.

New in version 1.2: Added “pre-ping” capability to the Pool class.

Custom / Legacy Pessimistic Ping

Before create_engine.pool_pre_ping was added, the “pre-ping” approach historically has been performed manually using the ConnectionEvents.engine_connect() engine event. The most common recipe for this is below, for reference purposes in case an application is already using such a recipe, or special behaviors are needed:

from sqlalchemy import exc
from sqlalchemy import event
from sqlalchemy import select

some_engine = create_engine(...)

@event.listens_for(some_engine, "engine_connect")
def ping_connection(connection, branch):
    if branch:
        # "branch" refers to a sub-connection of a connection,
        # we don't want to bother pinging on these.
        return

    # turn off "close with result".  This flag is only used with
    # "connectionless" execution, otherwise will be False in any case
    save_should_close_with_result = connection.should_close_with_result
    connection.should_close_with_result = False

    try:
        # run a SELECT 1.   use a core select() so that
        # the SELECT of a scalar value without a table is
        # appropriately formatted for the backend
        connection.scalar(select([1]))
    except exc.DBAPIError as err:
        # catch SQLAlchemy's DBAPIError, which is a wrapper
        # for the DBAPI's exception.  It includes a .connection_invalidated
        # attribute which specifies if this connection is a "disconnect"
        # condition, which is based on inspection of the original exception
        # by the dialect in use.
        if err.connection_invalidated:
            # run the same SELECT again - the connection will re-validate
            # itself and establish a new connection.  The disconnect detection
            # here also causes the whole connection pool to be invalidated
            # so that all stale connections are discarded.
            connection.scalar(select([1]))
        else:
            raise
    finally:
        # restore "close with result"
        connection.should_close_with_result = save_should_close_with_result

The above recipe has the advantage that we are making use of SQLAlchemy’s facilities for detecting those DBAPI exceptions that are known to indicate a “disconnect” situation, as well as the Engine object’s ability to correctly invalidate the current connection pool when this condition occurs and allowing the current Connection to re-validate onto a new DBAPI connection.

Disconnect Handling - Optimistic

When pessimistic handling is not employed, as well as when the database is shutdown and/or restarted in the middle of a connection’s period of use within a transaction, the other approach to dealing with stale / closed connections is to let SQLAlchemy handle disconnects as they occur, at which point all connections in the pool are invalidated, meaning they are assumed to be stale and will be refreshed upon next checkout. This behavior assumes the Pool is used in conjunction with a Engine. The Engine has logic which can detect disconnection events and refresh the pool automatically.

When the Connection attempts to use a DBAPI connection, and an exception is raised that corresponds to a “disconnect” event, the connection is invalidated. The Connection then calls the Pool.recreate() method, effectively invalidating all connections not currently checked out so that they are replaced with new ones upon next checkout. This flow is illustrated by the code example below:

from sqlalchemy import create_engine, exc
e = create_engine(...)
c = e.connect()

try:
    # suppose the database has been restarted.
    c.execute("SELECT * FROM table")
    c.close()
except exc.DBAPIError, e:
    # an exception is raised, Connection is invalidated.
    if e.connection_invalidated:
        print("Connection was invalidated!")

# after the invalidate event, a new connection
# starts with a new Pool
c = e.connect()
c.execute("SELECT * FROM table")

The above example illustrates that no special intervention is needed to refresh the pool, which continues normally after a disconnection event is detected. However, one database exception is raised, per each connection that is in use while the database unavailability event occurred. In a typical web application using an ORM Session, the above condition would correspond to a single request failing with a 500 error, then the web application continuing normally beyond that. Hence the approach is “optimistic” in that frequent database restarts are not anticipated.

Setting Pool Recycle

An additional setting that can augment the “optimistic” approach is to set the pool recycle parameter. This parameter prevents the pool from using a particular connection that has passed a certain age, and is appropriate for database backends such as MySQL that automatically close connections that have been stale after a particular period of time:

from sqlalchemy import create_engine
e = create_engine("mysql://scott:tiger@localhost/test", pool_recycle=3600)

Above, any DBAPI connection that has been open for more than one hour will be invalidated and replaced, upon next checkout. Note that the invalidation only occurs during checkout - not on any connections that are held in a checked out state. pool_recycle is a function of the Pool itself, independent of whether or not an Engine is in use.

More on Invalidation

The Pool provides “connection invalidation” services which allow both explicit invalidation of a connection as well as automatic invalidation in response to conditions that are determined to render a connection unusable.

“Invalidation” means that a particular DBAPI connection is removed from the pool and discarded. The .close() method is called on this connection if it is not clear that the connection itself might not be closed, however if this method fails, the exception is logged but the operation still proceeds.

When using a Engine, the Connection.invalidate() method is the usual entrypoint to explicit invalidation. Other conditions by which a DBAPI connection might be invalidated include:

  • a DBAPI exception such as OperationalError, raised when a method like connection.execute() is called, is detected as indicating a so-called “disconnect” condition. As the Python DBAPI provides no standard system for determining the nature of an exception, all SQLAlchemy dialects include a system called is_disconnect() which will examine the contents of an exception object, including the string message and any potential error codes included with it, in order to determine if this exception indicates that the connection is no longer usable. If this is the case, the _ConnectionFairy.invalidate() method is called and the DBAPI connection is then discarded.

  • When the connection is returned to the pool, and calling the connection.rollback() or connection.commit() methods, as dictated by the pool’s “reset on return” behavior, throws an exception. A final attempt at calling .close() on the connection will be made, and it is then discarded.

  • When a listener implementing PoolEvents.checkout() raises the DisconnectionError exception, indicating that the connection won’t be usable and a new connection attempt needs to be made.

All invalidations which occur will invoke the PoolEvents.invalidate() event.

Using FIFO vs. LIFO

The QueuePool class features a flag called QueuePool.use_lifo, which can also be accessed from create_engine() via the flag create_engine.pool_use_lifo. Setting this flag to True causes the pool’s “queue” behavior to instead be that of a “stack”, e.g. the last connection to be returned to the pool is the first one to be used on the next request. In contrast to the pool’s long- standing behavior of first-in-first-out, which produces a round-robin effect of using each connection in the pool in series, lifo mode allows excess connections to remain idle in the pool, allowing server-side timeout schemes to close these connections out. The difference between FIFO and LIFO is basically whether or not its desirable for the pool to keep a full set of connections ready to go even during idle periods:

engine = create_engine(
    "postgreql://", pool_use_lifo=True, pool_pre_ping=True)

Above, we also make use of the create_engine.pool_pre_ping flag so that connections which are closed from the server side are gracefully handled by the connection pool and replaced with a new connection.

Note that the flag only applies to QueuePool use.

New in version 1.3.

Using Connection Pools with Multiprocessing or os.fork()

It’s critical that when using a connection pool, and by extension when using an Engine created via create_engine(), that the pooled connections are not shared to a forked process. TCP connections are represented as file descriptors, which usually work across process boundaries, meaning this will cause concurrent access to the file descriptor on behalf of two or more entirely independent Python interpreter states.

Depending on specifics of the driver and OS, the issues that arise here range from non-working connections to socket connections that are used by multiple processes concurrently, leading to broken messaging (the latter case is typically the most common).

The SQLAlchemy Engine object refers to a connection pool of existing database connections. So when this object is replicated to a child process, the goal is to ensure that no database connections are carried over. There are three general approaches to this:

  1. Disable pooling using NullPool. This is the most simplistic, one shot system that prevents the Engine from using any connection more than once:

    from sqlalchemy.pool import NullPool
    engine = create_engine("mysql://user:pass@host/dbname", poolclass=NullPool)
  2. Call Engine.dispose() on any given Engine directly before the new process is started, so that the new process will create new connections, as well as not attempt to close connections that were shared from the parent which can impact the parent’s subsequent use of those connections. This is the recommended approach:

    engine = create_engine("mysql://user:pass@host/dbname")
    
    def run_in_process():
        with engine.connect() as conn:
            conn.execute(text("..."))
    
    # before process starts, ensure engine.dispose() is called
    engine.dispose()
    p = Process(target=run_in_process)
    p.start()
  3. Alternatively, if the Engine is only to be used in child processes, and will not be used from the parent process subsequent to the creation of child forks, the dispose may be within the child process right as it begins:

    engine = create_engine("mysql+mysqldb://user:pass@host/dbname")
    
    def run_in_process():
        # process starts. ensure engine.dispose() is called just once
        # at the beginning.  note this cause parent process connections
        # to be closed for most drivers
        engine.dispose()
    
        with engine.connect() as conn:
            conn.execute(text("..."))
    
    p = Process(target=run_in_process)
    p.start()
    
    # after child process starts, "engine" above should not be used within
    # the parent process for connectivity, without calling
    # engine.dispose() first
  4. An event handler can be applied to the connection pool that tests for connections being shared across process boundaries, and invalidates them:

    from sqlalchemy import event
    from sqlalchemy import exc
    import os
    
    engine = create_engine("...")
    
    @event.listens_for(engine, "connect")
    def connect(dbapi_connection, connection_record):
        connection_record.info['pid'] = os.getpid()
    
    @event.listens_for(engine, "checkout")
    def checkout(dbapi_connection, connection_record, connection_proxy):
        pid = os.getpid()
        if connection_record.info['pid'] != pid:
            connection_record.connection = connection_proxy.connection = None
            raise exc.DisconnectionError(
                    "Connection record belongs to pid %s, "
                    "attempting to check out in pid %s" %
                    (connection_record.info['pid'], pid)
            )

    Above, we use an approach similar to that described in Disconnect Handling - Pessimistic to treat a DBAPI connection that originated in a different parent process as an “invalid” connection, coercing the pool to recycle the connection record to make a new connection.

The above strategies will accommodate the case of an Engine being shared among processes. The above steps alone are not sufficient for the case of sharing a specific Connection over a process boundary; prefer to keep the scope of a particular Connection local to a single process (and thread). It’s additionally not supported to share any kind of ongoing transactional state directly across a process boundary, such as an ORM Session object that’s begun a transaction and references active Connection instances; again prefer to create new Session objects in new processes.

API Documentation - Available Pool Implementations

Object Name Description

_ConnectionFairy

Proxies a DBAPI connection and provides return-on-dereference support.

_ConnectionRecord

Internal object which maintains an individual DBAPI connection referenced by a Pool.

AssertionPool

A Pool that allows at most one checked out connection at any given time.

NullPool

A Pool which does not pool connections.

Pool

Abstract base class for connection pools.

QueuePool

A Pool that imposes a limit on the number of open connections.

SingletonThreadPool

A Pool that maintains one connection per thread.

StaticPool

A Pool of exactly one connection, used for all requests.

class sqlalchemy.pool.Pool(creator, recycle=-1, echo=None, use_threadlocal=False, logging_name=None, reset_on_return=True, listeners=None, events=None, dialect=None, pre_ping=False, _dispatch=None)

Abstract base class for connection pools.

method sqlalchemy.pool.Pool.__init__(creator, recycle=-1, echo=None, use_threadlocal=False, logging_name=None, reset_on_return=True, listeners=None, events=None, dialect=None, pre_ping=False, _dispatch=None)

Construct a Pool.

Parameters:
  • creator – a callable function that returns a DB-API connection object. The function will be called with parameters.

  • recycle – If set to a value other than -1, number of seconds between connection recycling, which means upon checkout, if this timeout is surpassed the connection will be closed and replaced with a newly opened connection. Defaults to -1.

  • logging_name – String identifier which will be used within the “name” field of logging records generated within the “sqlalchemy.pool” logger. Defaults to a hexstring of the object’s id.

  • echo

    if True, the connection pool will log informational output such as when connections are invalidated as well as when connections are recycled to the default log handler, which defaults to sys.stdout for output.. If set to the string "debug", the logging will include pool checkouts and checkins.

    The Pool.echo parameter can also be set from the create_engine() call by using the create_engine.echo_pool parameter.

    See also

    Configuring Logging - further detail on how to configure logging.

  • use_threadlocal

    If set to True, repeated calls to connect() within the same application thread will be guaranteed to return the same connection object that is already checked out. This is a legacy use case and the flag has no effect when using the pool with a Engine object.

    Deprecated since version 1.3: The Pool.use_threadlocal parameter is deprecated and will be removed in a future release.

  • reset_on_return

    Determine steps to take on connections as they are returned to the pool. reset_on_return can have any of these values:

    • "rollback" - call rollback() on the connection, to release locks and transaction resources. This is the default value. The vast majority of use cases should leave this value set.

    • True - same as ‘rollback’, this is here for backwards compatibility.

    • "commit" - call commit() on the connection, to release locks and transaction resources. A commit here may be desirable for databases that cache query plans if a commit is emitted, such as Microsoft SQL Server. However, this value is more dangerous than ‘rollback’ because any data changes present on the transaction are committed unconditionally.

    • None - don’t do anything on the connection. This setting should generally only be made on a database that has no transaction support at all, namely MySQL MyISAM; when used on this backend, performance can be improved as the “rollback” call is still expensive on MySQL. It is strongly recommended that this setting not be used for transaction-supporting databases in conjunction with a persistent pool such as QueuePool, as it opens the possibility for connections still in a transaction to be idle in the pool. The setting may be appropriate in the case of NullPool or special circumstances where the connection pool in use is not being used to maintain connection lifecycle.

    • False - same as None, this is here for backwards compatibility.

  • events – a list of 2-tuples, each of the form (callable, target) which will be passed to listen() upon construction. Provided here so that event listeners can be assigned via create_engine() before dialect-level listeners are applied.

  • listeners

    A list of PoolListener-like objects or dictionaries of callables that receive events when DB-API connections are created, checked out and checked in to the pool.

    Deprecated since version 0.7: PoolListener is deprecated in favor of the PoolEvents listener interface. The Pool.listeners parameter will be removed in a future release.

  • dialect

    a Dialect that will handle the job of calling rollback(), close(), or commit() on DBAPI connections. If omitted, a built-in “stub” dialect is used. Applications that make use of create_engine() should not use this parameter as it is handled by the engine creation strategy.

    New in version 1.1: - dialect is now a public parameter to the Pool.

  • pre_ping

    if True, the pool will emit a “ping” (typically “SELECT 1”, but is dialect-specific) on the connection upon checkout, to test if the connection is alive or not. If not, the connection is transparently re-connected and upon success, all other pooled connections established prior to that timestamp are invalidated. Requires that a dialect is passed as well to interpret the disconnection error.

    New in version 1.2.

method sqlalchemy.pool.Pool.connect()

Return a DBAPI connection from the pool.

The connection is instrumented such that when its close() method is called, the connection will be returned to the pool.

method sqlalchemy.pool.Pool.dispose()

Dispose of this pool.

This method leaves the possibility of checked-out connections remaining open, as it only affects connections that are idle in the pool.

See also

Pool.recreate()

method sqlalchemy.pool.Pool.recreate()

Return a new Pool, of the same class as this one and configured with identical creation arguments.

This method is used in conjunction with dispose() to close out an entire Pool and create a new one in its place.

method sqlalchemy.pool.Pool.unique_connection()

Produce a DBAPI connection that is not referenced by any thread-local context.

This method is equivalent to Pool.connect() when the Pool.use_threadlocal flag is not set to True. When Pool.use_threadlocal is True, the Pool.unique_connection() method provides a means of bypassing the threadlocal context.

class sqlalchemy.pool.QueuePool(creator, pool_size=5, max_overflow=10, timeout=30, use_lifo=False, **kw)

A Pool that imposes a limit on the number of open connections.

QueuePool is the default pooling implementation used for all Engine objects, unless the SQLite dialect is in use.

method sqlalchemy.pool.QueuePool.__init__(creator, pool_size=5, max_overflow=10, timeout=30, use_lifo=False, **kw)

Construct a QueuePool.

Parameters:
  • creator – a callable function that returns a DB-API connection object, same as that of Pool.creator.

  • pool_size – The size of the pool to be maintained, defaults to 5. This is the largest number of connections that will be kept persistently in the pool. Note that the pool begins with no connections; once this number of connections is requested, that number of connections will remain. pool_size can be set to 0 to indicate no size limit; to disable pooling, use a NullPool instead.

  • max_overflow – The maximum overflow size of the pool. When the number of checked-out connections reaches the size set in pool_size, additional connections will be returned up to this limit. When those additional connections are returned to the pool, they are disconnected and discarded. It follows then that the total number of simultaneous connections the pool will allow is pool_size + max_overflow, and the total number of “sleeping” connections the pool will allow is pool_size. max_overflow can be set to -1 to indicate no overflow limit; no limit will be placed on the total number of concurrent connections. Defaults to 10.

  • timeout – The number of seconds to wait before giving up on returning a connection. Defaults to 30.

  • use_lifo

    use LIFO (last-in-first-out) when retrieving connections instead of FIFO (first-in-first-out). Using LIFO, a server-side timeout scheme can reduce the number of connections used during non-peak periods of use. When planning for server-side timeouts, ensure that a recycle or pre-ping strategy is in use to gracefully handle stale connections.

    New in version 1.3.

  • **kw – Other keyword arguments including Pool.recycle, Pool.echo, Pool.reset_on_return and others are passed to the Pool constructor.

method sqlalchemy.pool.QueuePool.connect()

inherited from the Pool.connect() method of Pool

Return a DBAPI connection from the pool.

The connection is instrumented such that when its close() method is called, the connection will be returned to the pool.

method sqlalchemy.pool.QueuePool.unique_connection()

inherited from the Pool.unique_connection() method of Pool

Produce a DBAPI connection that is not referenced by any thread-local context.

This method is equivalent to Pool.connect() when the Pool.use_threadlocal flag is not set to True. When Pool.use_threadlocal is True, the Pool.unique_connection() method provides a means of bypassing the threadlocal context.

class sqlalchemy.pool.SingletonThreadPool(creator, pool_size=5, **kw)

A Pool that maintains one connection per thread.

Maintains one connection per each thread, never moving a connection to a thread other than the one which it was created in.

Warning

the SingletonThreadPool will call .close() on arbitrary connections that exist beyond the size setting of pool_size, e.g. if more unique thread identities than what pool_size states are used. This cleanup is non-deterministic and not sensitive to whether or not the connections linked to those thread identities are currently in use.

SingletonThreadPool may be improved in a future release, however in its current status it is generally used only for test scenarios using a SQLite :memory: database and is not recommended for production use.

Options are the same as those of Pool, as well as:

Parameters:

pool_size – The number of threads in which to maintain connections at once. Defaults to five.

SingletonThreadPool is used by the SQLite dialect automatically when a memory-based database is used. See SQLite.

Members

__init__()

method sqlalchemy.pool.SingletonThreadPool.__init__(creator, pool_size=5, **kw)

Construct a Pool.

Parameters:
  • creator – a callable function that returns a DB-API connection object. The function will be called with parameters.

  • recycle – If set to a value other than -1, number of seconds between connection recycling, which means upon checkout, if this timeout is surpassed the connection will be closed and replaced with a newly opened connection. Defaults to -1.

  • logging_name – String identifier which will be used within the “name” field of logging records generated within the “sqlalchemy.pool” logger. Defaults to a hexstring of the object’s id.

  • echo

    if True, the connection pool will log informational output such as when connections are invalidated as well as when connections are recycled to the default log handler, which defaults to sys.stdout for output.. If set to the string "debug", the logging will include pool checkouts and checkins.

    The Pool.echo parameter can also be set from the create_engine() call by using the create_engine.echo_pool parameter.

    See also

    Configuring Logging - further detail on how to configure logging.

  • use_threadlocal

    If set to True, repeated calls to connect() within the same application thread will be guaranteed to return the same connection object that is already checked out. This is a legacy use case and the flag has no effect when using the pool with a Engine object.

    Deprecated since version 1.3: The Pool.use_threadlocal parameter is deprecated and will be removed in a future release.

  • reset_on_return

    Determine steps to take on connections as they are returned to the pool. reset_on_return can have any of these values:

    • "rollback" - call rollback() on the connection, to release locks and transaction resources. This is the default value. The vast majority of use cases should leave this value set.

    • True - same as ‘rollback’, this is here for backwards compatibility.

    • "commit" - call commit() on the connection, to release locks and transaction resources. A commit here may be desirable for databases that cache query plans if a commit is emitted, such as Microsoft SQL Server. However, this value is more dangerous than ‘rollback’ because any data changes present on the transaction are committed unconditionally.

    • None - don’t do anything on the connection. This setting should generally only be made on a database that has no transaction support at all, namely MySQL MyISAM; when used on this backend, performance can be improved as the “rollback” call is still expensive on MySQL. It is strongly recommended that this setting not be used for transaction-supporting databases in conjunction with a persistent pool such as QueuePool, as it opens the possibility for connections still in a transaction to be idle in the pool. The setting may be appropriate in the case of NullPool or special circumstances where the connection pool in use is not being used to maintain connection lifecycle.

    • False - same as None, this is here for backwards compatibility.

  • events – a list of 2-tuples, each of the form (callable, target) which will be passed to listen() upon construction. Provided here so that event listeners can be assigned via create_engine() before dialect-level listeners are applied.

  • listeners

    A list of PoolListener-like objects or dictionaries of callables that receive events when DB-API connections are created, checked out and checked in to the pool.

    Deprecated since version 0.7: PoolListener is deprecated in favor of the PoolEvents listener interface. The Pool.listeners parameter will be removed in a future release.

  • dialect

    a Dialect that will handle the job of calling rollback(), close(), or commit() on DBAPI connections. If omitted, a built-in “stub” dialect is used. Applications that make use of create_engine() should not use this parameter as it is handled by the engine creation strategy.

    New in version 1.1: - dialect is now a public parameter to the Pool.

  • pre_ping

    if True, the pool will emit a “ping” (typically “SELECT 1”, but is dialect-specific) on the connection upon checkout, to test if the connection is alive or not. If not, the connection is transparently re-connected and upon success, all other pooled connections established prior to that timestamp are invalidated. Requires that a dialect is passed as well to interpret the disconnection error.

    New in version 1.2.

class sqlalchemy.pool.AssertionPool(*args, **kw)

A Pool that allows at most one checked out connection at any given time.

This will raise an exception if more than one connection is checked out at a time. Useful for debugging code that is using more connections than desired.

class sqlalchemy.pool.NullPool(creator, recycle=-1, echo=None, use_threadlocal=False, logging_name=None, reset_on_return=True, listeners=None, events=None, dialect=None, pre_ping=False, _dispatch=None)

A Pool which does not pool connections.

Instead it literally opens and closes the underlying DB-API connection per each connection open/close.

Reconnect-related functions such as recycle and connection invalidation are not supported by this Pool implementation, since no connections are held persistently.

class sqlalchemy.pool.StaticPool(creator, recycle=-1, echo=None, use_threadlocal=False, logging_name=None, reset_on_return=True, listeners=None, events=None, dialect=None, pre_ping=False, _dispatch=None)

A Pool of exactly one connection, used for all requests.

Reconnect-related functions such as recycle and connection invalidation (which is also used to support auto-reconnect) are not currently supported by this Pool implementation but may be implemented in a future release.

class sqlalchemy.pool._ConnectionFairy(dbapi_connection, connection_record, echo)

Proxies a DBAPI connection and provides return-on-dereference support.

This is an internal object used by the Pool implementation to provide context management to a DBAPI connection delivered by that Pool.

The name “fairy” is inspired by the fact that the _ConnectionFairy object’s lifespan is transitory, as it lasts only for the length of a specific DBAPI connection being checked out from the pool, and additionally that as a transparent proxy, it is mostly invisible.

attribute sqlalchemy.pool._ConnectionFairy._connection_record = None

A reference to the _ConnectionRecord object associated with the DBAPI connection.

This is currently an internal accessor which is subject to change.

attribute sqlalchemy.pool._ConnectionFairy.connection = None

A reference to the actual DBAPI connection being tracked.

method sqlalchemy.pool._ConnectionFairy.cursor(*args, **kwargs)

Return a new DBAPI cursor for the underlying connection.

This method is a proxy for the connection.cursor() DBAPI method.

method sqlalchemy.pool._ConnectionFairy.detach()

Separate this connection from its Pool.

This means that the connection will no longer be returned to the pool when closed, and will instead be literally closed. The containing ConnectionRecord is separated from the DB-API connection, and will create a new connection when next used.

Note that any overall connection limiting constraints imposed by a Pool implementation may be violated after a detach, as the detached connection is removed from the pool’s knowledge and control.

attribute sqlalchemy.pool._ConnectionFairy.info

Info dictionary associated with the underlying DBAPI connection referred to by this ConnectionFairy, allowing user-defined data to be associated with the connection.

The data here will follow along with the DBAPI connection including after it is returned to the connection pool and used again in subsequent instances of _ConnectionFairy. It is shared with the _ConnectionRecord.info and Connection.info accessors.

The dictionary associated with a particular DBAPI connection is discarded when the connection itself is discarded.

method sqlalchemy.pool._ConnectionFairy.invalidate(e=None, soft=False)

Mark this connection as invalidated.

This method can be called directly, and is also called as a result of the Connection.invalidate() method. When invoked, the DBAPI connection is immediately closed and discarded from further use by the pool. The invalidation mechanism proceeds via the _ConnectionRecord.invalidate() internal method.

Parameters:
  • e – an exception object indicating a reason for the invalidation.

  • soft

    if True, the connection isn’t closed; instead, this connection will be recycled on next checkout.

    New in version 1.0.3.

attribute sqlalchemy.pool._ConnectionFairy.is_valid

Return True if this _ConnectionFairy still refers to an active DBAPI connection.

attribute sqlalchemy.pool._ConnectionFairy.record_info

Info dictionary associated with the _ConnectionRecord container referred to by this :class:.ConnectionFairy`.

Unlike the _ConnectionFairy.info dictionary, the lifespan of this dictionary is persistent across connections that are disconnected and/or invalidated within the lifespan of a _ConnectionRecord.

New in version 1.1.

class sqlalchemy.pool._ConnectionRecord(pool, connect=True)

Internal object which maintains an individual DBAPI connection referenced by a Pool.

The _ConnectionRecord object always exists for any particular DBAPI connection whether or not that DBAPI connection has been “checked out”. This is in contrast to the _ConnectionFairy which is only a public facade to the DBAPI connection while it is checked out.

A _ConnectionRecord may exist for a span longer than that of a single DBAPI connection. For example, if the _ConnectionRecord.invalidate() method is called, the DBAPI connection associated with this _ConnectionRecord will be discarded, but the _ConnectionRecord may be used again, in which case a new DBAPI connection is produced when the Pool next uses this record.

The _ConnectionRecord is delivered along with connection pool events, including PoolEvents.connect() and PoolEvents.checkout(), however _ConnectionRecord still remains an internal object whose API and internals may change.

See also

_ConnectionFairy

attribute sqlalchemy.pool._ConnectionRecord.connection = None

A reference to the actual DBAPI connection being tracked.

May be None if this _ConnectionRecord has been marked as invalidated; a new DBAPI connection may replace it if the owning pool calls upon this _ConnectionRecord to reconnect.

attribute sqlalchemy.pool._ConnectionRecord.info

The .info dictionary associated with the DBAPI connection.

This dictionary is shared among the _ConnectionFairy.info and Connection.info accessors.

Note

The lifespan of this dictionary is linked to the DBAPI connection itself, meaning that it is discarded each time the DBAPI connection is closed and/or invalidated. The _ConnectionRecord.record_info dictionary remains persistent throughout the lifespan of the _ConnectionRecord container.

method sqlalchemy.pool._ConnectionRecord.invalidate(e=None, soft=False)

Invalidate the DBAPI connection held by this _ConnectionRecord.

This method is called for all connection invalidations, including when the _ConnectionFairy.invalidate() or Connection.invalidate() methods are called, as well as when any so-called “automatic invalidation” condition occurs.

Parameters:
  • e – an exception object indicating a reason for the invalidation.

  • soft

    if True, the connection isn’t closed; instead, this connection will be recycled on next checkout.

    New in version 1.0.3.

attribute sqlalchemy.pool._ConnectionRecord.record_info

An “info’ dictionary associated with the connection record itself.

Unlike the _ConnectionRecord.info dictionary, which is linked to the lifespan of the DBAPI connection, this dictionary is linked to the lifespan of the _ConnectionRecord container itself and will remain persistent throughout the life of the _ConnectionRecord.

New in version 1.1.