Operation Reference

This file provides documentation on Alembic migration directives.

The directives here are used within user-defined migration files, within the upgrade() and downgrade() functions, as well as any functions further invoked by those.

All directives exist as methods on a class called Operations. When migration scripts are run, this object is made available to the script via the alembic.op datamember, which is a proxy to an actual instance of Operations. Currently, alembic.op is a real Python module, populated with individual proxies for each method on Operations, so symbols can be imported safely from the alembic.op namespace.

A key design philosophy to the alembic.operations methods is that to the greatest degree possible, they internally generate the appropriate SQLAlchemy metadata, typically involving Table and Constraint objects. This so that migration instructions can be given in terms of just the string names and/or flags involved. The exceptions to this rule include the add_column() and create_table() directives, which require full Column objects, though the table metadata is still generated here.

The functions here all require that a MigrationContext has been configured within the env.py script first, which is typically via EnvironmentContext.configure(). Under normal circumstances they are called from an actual migration script, which itself would be invoked by the EnvironmentContext.run_migrations() method.

class alembic.operations.Operations(migration_context)

Define high level migration operations.

Each operation corresponds to some schema migration operation, executed against a particular MigrationContext which in turn represents connectivity to a database, or a file output stream.

While Operations is normally configured as part of the EnvironmentContext.run_migrations() method called from an env.py script, a standalone Operations instance can be made for use cases external to regular Alembic migrations by passing in a MigrationContext:

from alembic.migration import MigrationContext
from alembic.operations import Operations

conn = myengine.connect()
ctx = MigrationContext.configure(conn)
op = Operations(ctx)

op.alter_column("t", "c", nullable=True)

Construct a new Operations

Parameters:migration_context – a MigrationContext instance.
add_column(table_name, column, schema=None)

Issue an “add column” instruction using the current migration context.

e.g.:

from alembic import op
from sqlalchemy import Column, String

op.add_column('organization',
    Column('name', String())
)

The provided Column object can also specify a ForeignKey, referencing a remote table name. Alembic will automatically generate a stub “referenced” table and emit a second ALTER statement in order to add the constraint separately:

from alembic import op
from sqlalchemy import Column, INTEGER, ForeignKey

op.add_column('organization',
    Column('account_id', INTEGER, ForeignKey('accounts.id'))
)

Note that this statement uses the Column construct as is from the SQLAlchemy library. In particular, default values to be created on the database side are specified using the server_default parameter, and not default which only specifies Python-side defaults:

from alembic import op
from sqlalchemy import Column, TIMESTAMP, func

# specify "DEFAULT NOW" along with the column add
op.add_column('account',
    Column('timestamp', TIMESTAMP, server_default=func.now())
)
Parameters:
  • table_name – String name of the parent table.
  • column – a sqlalchemy.schema.Column object representing the new column.
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

alter_column(table_name, column_name, nullable=None, server_default=False, name=None, type_=None, autoincrement=None, existing_type=None, existing_server_default=False, existing_nullable=None, existing_autoincrement=None, schema=None)

Issue an “alter column” instruction using the current migration context.

Generally, only that aspect of the column which is being changed, i.e. name, type, nullability, default, needs to be specified. Multiple changes can also be specified at once and the backend should “do the right thing”, emitting each change either separately or together as the backend allows.

MySQL has special requirements here, since MySQL cannot ALTER a column without a full specification. When producing MySQL-compatible migration files, it is recommended that the existing_type, existing_server_default, and existing_nullable parameters be present, if not being altered.

Type changes which are against the SQLAlchemy “schema” types Boolean and Enum may also add or drop constraints which accompany those types on backends that don’t support them natively. The existing_server_default argument is used in this case as well to remove a previous constraint.

Parameters:
  • table_name – string name of the target table.
  • column_name – string name of the target column, as it exists before the operation begins.
  • nullable – Optional; specify True or False to alter the column’s nullability.
  • server_default – Optional; specify a string SQL expression, text(), or DefaultClause to indicate an alteration to the column’s default value. Set to None to have the default removed.
  • name – Optional; specify a string name here to indicate the new name within a column rename operation.
  • type – Optional; a TypeEngine type object to specify a change to the column’s type. For SQLAlchemy types that also indicate a constraint (i.e. Boolean, Enum), the constraint is also generated.
  • autoincrement – set the AUTO_INCREMENT flag of the column; currently understood by the MySQL dialect.
  • existing_type – Optional; a TypeEngine type object to specify the previous type. This is required for all MySQL column alter operations that don’t otherwise specify a new type, as well as for when nullability is being changed on a SQL Server column. It is also used if the type is a so-called SQLlchemy “schema” type which may define a constraint (i.e. Boolean, Enum), so that the constraint can be dropped.
  • existing_server_default – Optional; The existing default value of the column. Required on MySQL if an existing default is not being changed; else MySQL removes the default.
  • existing_nullable – Optional; the existing nullability of the column. Required on MySQL if the existing nullability is not being changed; else MySQL sets this to NULL.
  • existing_autoincrement – Optional; the existing autoincrement of the column. Used for MySQL’s system of altering a column that specifies AUTO_INCREMENT.
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

bulk_insert(table, rows)

Issue a “bulk insert” operation using the current migration context.

This provides a means of representing an INSERT of multiple rows which works equally well in the context of executing on a live connection as well as that of generating a SQL script. In the case of a SQL script, the values are rendered inline into the statement.

e.g.:

from datetime import date
from sqlalchemy.sql import table, column
from sqlalchemy import String, Integer, Date

# Create an ad-hoc table to use for the insert statement.
accounts_table = table('account',
    column('id', Integer),
    column('name', String),
    column('create_date', Date)
)

bulk_insert(accounts_table,
    [
        {'id':1, 'name':'John Smith',
                'create_date':date(2010, 10, 5)},
        {'id':2, 'name':'Ed Williams',
                'create_date':date(2007, 5, 27)},
        {'id':3, 'name':'Wendy Jones',
                'create_date':date(2008, 8, 15)},
    ]
)
create_check_constraint(name, source, condition, schema=None, **kw)

Issue a “create check constraint” instruction using the current migration context.

e.g.:

from alembic import op
from sqlalchemy.sql import column, func

op.create_check_constraint(
    "ck_user_name_len",
    "user",
    func.len(column('name')) > 5
)

CHECK constraints are usually against a SQL expression, so ad-hoc table metadata is usually needed. The function will convert the given arguments into a sqlalchemy.schema.CheckConstraint bound to an anonymous table in order to emit the CREATE statement.

Parameters:
  • name – Name of the check constraint. The name is necessary so that an ALTER statement can be emitted. For setups that use an automated naming scheme such as that described at NamingConventions, name here can be None, as the event listener will apply the name to the constraint object when it is associated with the table.
  • source – String name of the source table.
  • condition – SQL expression that’s the condition of the constraint. Can be a string or SQLAlchemy expression language structure.
  • deferrable – optional bool. If set, emit DEFERRABLE or NOT DEFERRABLE when issuing DDL for this constraint.
  • initially – optional string. If set, emit INITIALLY <value> when issuing DDL for this constraint.
  • schema

    Optional schema name to operate within.

    ..versionadded:: 0.4.0

create_foreign_key(name, source, referent, local_cols, remote_cols, onupdate=None, ondelete=None, source_schema=None, referent_schema=None)

Issue a “create foreign key” instruction using the current migration context.

e.g.:

from alembic import op
op.create_foreign_key(
            "fk_user_address", "address",
            "user", ["user_id"], ["id"])

This internally generates a Table object containing the necessary columns, then generates a new ForeignKeyConstraint object which it then associates with the Table. Any event listeners associated with this action will be fired off normally. The AddConstraint construct is ultimately used to generate the ALTER statement.

Parameters:
  • name

    Name of the foreign key constraint. The name is necessary so that an ALTER statement can be emitted. For setups that use an automated naming scheme such as that described at NamingConventions, name here can be None, as the event listener will apply the name to the constraint object when it is associated with the table.

  • source – String name of the source table.
  • referent – String name of the destination table.
  • local_cols – a list of string column names in the source table.
  • remote_cols – a list of string column names in the remote table.
  • onupdate – Optional string. If set, emit ON UPDATE <value> when issuing DDL for this constraint. Typical values include CASCADE, DELETE and RESTRICT.
  • ondelete – Optional string. If set, emit ON DELETE <value> when issuing DDL for this constraint. Typical values include CASCADE, DELETE and RESTRICT.
  • source_schema – Optional schema name of the source table.
  • referent_schema – Optional schema name of the destination table.
create_index(name, tablename, columns, schema=None, **kw)

Issue a “create index” instruction using the current migration context.

e.g.:

from alembic import op
op.create_index('ik_test', 't1', ['foo', 'bar'])
Parameters:
  • name – name of the index.
  • tablename – name of the owning table.
  • columns – a list of string column names in the table.
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

create_table(name, *columns, **kw)

Issue a “create table” instruction using the current migration context.

This directive receives an argument list similar to that of the traditional sqlalchemy.schema.Table construct, but without the metadata:

from sqlalchemy import INTEGER, VARCHAR, NVARCHAR, Column
from alembic import op

op.create_table(
    'account',
    Column('id', INTEGER, primary_key=True),
    Column('name', VARCHAR(50), nullable=False),
    Column('description', NVARCHAR(200))
    Column('timestamp', TIMESTAMP, server_default=func.now())
)

Note that create_table() accepts Column constructs directly from the SQLAlchemy library. In particular, default values to be created on the database side are specified using the server_default parameter, and not default which only specifies Python-side defaults:

from alembic import op
from sqlalchemy import Column, TIMESTAMP, func

# specify "DEFAULT NOW" along with the "timestamp" column
op.create_table('account',
    Column('id', INTEGER, primary_key=True),
    Column('timestamp', TIMESTAMP, server_default=func.now())
)
Parameters:
  • name – Name of the table
  • *columns – collection of Column objects within the table, as well as optional Constraint objects and Index objects.
  • schema – Optional schema name to operate within.
  • **kw – Other keyword arguments are passed to the underlying sqlalchemy.schema.Table object created for the command.
create_unique_constraint(name, source, local_cols, schema=None, **kw)

Issue a “create unique constraint” instruction using the current migration context.

e.g.:

from alembic import op
op.create_unique_constraint("uq_user_name", "user", ["name"])

This internally generates a Table object containing the necessary columns, then generates a new UniqueConstraint object which it then associates with the Table. Any event listeners associated with this action will be fired off normally. The AddConstraint construct is ultimately used to generate the ALTER statement.

Parameters:
  • name

    Name of the unique constraint. The name is necessary so that an ALTER statement can be emitted. For setups that use an automated naming scheme such as that described at NamingConventions, name here can be None, as the event listener will apply the name to the constraint object when it is associated with the table.

  • source – String name of the source table. Dotted schema names are supported.
  • local_cols – a list of string column names in the source table.
  • deferrable – optional bool. If set, emit DEFERRABLE or NOT DEFERRABLE when issuing DDL for this constraint.
  • initially – optional string. If set, emit INITIALLY <value> when issuing DDL for this constraint.
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

drop_column(table_name, column_name, **kw)

Issue a “drop column” instruction using the current migration context.

e.g.:

drop_column('organization', 'account_id')
Parameters:
  • table_name – name of table
  • column_name – name of column
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

  • mssql_drop_check – Optional boolean. When True, on Microsoft SQL Server only, first drop the CHECK constraint on the column using a SQL-script-compatible block that selects into a @variable from sys.check_constraints, then exec’s a separate DROP CONSTRAINT for that constraint.
  • mssql_drop_default – Optional boolean. When True, on Microsoft SQL Server only, first drop the DEFAULT constraint on the column using a SQL-script-compatible block that selects into a @variable from sys.default_constraints, then exec’s a separate DROP CONSTRAINT for that default.
drop_constraint(name, tablename, type=None, schema=None)

Drop a constraint of the given name, typically via DROP CONSTRAINT.

Parameters:
  • name – name of the constraint.
  • tablename – tablename.
  • type

    optional, required on MySQL. can be ‘foreignkey’, ‘primary’, ‘unique’, or ‘check’.

    New in version 0.3.6: ‘primary’ qualfier to enable dropping of MySQL primary key constraints.

  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

drop_index(name, tablename=None, schema=None)

Issue a “drop index” instruction using the current migration context.

e.g.:

drop_index("accounts")
Parameters:
  • name – name of the index.
  • tablename – name of the owning table. Some backends such as Microsoft SQL Server require this.
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

drop_table(name, **kw)

Issue a “drop table” instruction using the current migration context.

e.g.:

drop_table("accounts")
Parameters:
  • name – Name of the table
  • schema

    Optional schema name to operate within.

    New in version 0.4.0.

  • **kw – Other keyword arguments are passed to the underlying sqlalchemy.schema.Table object created for the command.
execute(sql, execution_options=None)

Execute the given SQL using the current migration context.

In a SQL script context, the statement is emitted directly to the output stream. There is no return result, however, as this function is oriented towards generating a change script that can run in “offline” mode. For full interaction with a connected database, use the “bind” available from the context:

from alembic import op
connection = op.get_bind()

Also note that any parameterized statement here will not work in offline mode - INSERT, UPDATE and DELETE statements which refer to literal values would need to render inline expressions. For simple use cases, the inline_literal() function can be used for rudimentary quoting of string values. For “bulk” inserts, consider using bulk_insert().

For example, to emit an UPDATE statement which is equally compatible with both online and offline mode:

from sqlalchemy.sql import table, column
from sqlalchemy import String
from alembic import op

account = table('account',
    column('name', String)
)
op.execute(
    account.update().\
        where(account.c.name==op.inline_literal('account 1')).\
        values({'name':op.inline_literal('account 2')})
        )

Note above we also used the SQLAlchemy sqlalchemy.sql.expression.table() and sqlalchemy.sql.expression.column() constructs to make a brief, ad-hoc table construct just for our UPDATE statement. A full Table construct of course works perfectly fine as well, though note it’s a recommended practice to at least ensure the definition of a table is self-contained within the migration script, rather than imported from a module that may break compatibility with older migrations.

Parameters:sql – Any legal SQLAlchemy expression, including:
Parameters:execution_options – Optional dictionary of execution options, will be passed to sqlalchemy.engine.Connection.execution_options().
get_bind()

Return the current ‘bind’.

Under normal circumstances, this is the Connection currently being used to emit SQL to the database.

In a SQL script context, this value is None. [TODO: verify this]

get_context()

Return the MigrationContext object that’s currently in use.

inline_literal(value, type_=None)

Produce an ‘inline literal’ expression, suitable for using in an INSERT, UPDATE, or DELETE statement.

When using Alembic in “offline” mode, CRUD operations aren’t compatible with SQLAlchemy’s default behavior surrounding literal values, which is that they are converted into bound values and passed separately into the execute() method of the DBAPI cursor. An offline SQL script needs to have these rendered inline. While it should always be noted that inline literal values are an enormous security hole in an application that handles untrusted input, a schema migration is not run in this context, so literals are safe to render inline, with the caveat that advanced types like dates may not be supported directly by SQLAlchemy.

See execute() for an example usage of inline_literal().

Parameters:
  • value – The value to render. Strings, integers, and simple numerics should be supported. Other types like boolean, dates, etc. may or may not be supported yet by various backends.
  • type – optional - a sqlalchemy.types.TypeEngine subclass stating the type of this value. In SQLAlchemy expressions, this is usually derived automatically from the Python type of the value itself, as well as based on the context in which the value is used.
rename_table(old_table_name, new_table_name, schema=None)

Emit an ALTER TABLE to rename a table.

Parameters:
  • old_table_name – old name.
  • new_table_name – new name.
  • schema – Optional schema name to operate within.

Previous topic

Tutorial

Next topic

API Details

This Page