.. changelog::
:version: 0.8.0
+ .. change::
+ :tags: sql, feature
+ :tickets: 695
+
+ :class:`.Index` now supports arbitrary SQL expressions and/or
+ functions, in addition to straight columns. Common modifiers
+ include using ``somecolumn.desc()`` for a descending index and
+ ``func.lower(somecolumn)`` for a case-insensitive index, depending on the
+ capabilities of the target backend.
+
.. change::
:tags: mssql, bug
:tickets: 2638
{sql}i.create(engine)
CREATE INDEX someindex ON mytable (col5){stop}
+Functional Indexes
+~~~~~~~~~~~~~~~~~~~
+
+:class:`.Index` supports SQL and function expressions, as supported by the
+target backend. To create an index against a column using a descending
+value, the :meth:`.ColumnElement.desc` modifier may be used::
+
+ from sqlalchemy import Index
+
+ Index('someindex', mytable.c.somecol.desc())
+
+Or with a backend that supports functional indexes such as Postgresql,
+a "case insensitive" index can be created using the ``lower()`` function::
+
+ from sqlalchemy import func, Index
+
+ Index('someindex', func.lower(mytable.c.somecol))
+
+.. versionadded:: 0.8 :class:`.Index` supports SQL expressions and functions
+ as well as plain columns.
+
+Index API
+---------
+
.. autoclass:: Index
:show-inheritance:
:members:
def visit_drop_index(self, drop):
return "\nDROP INDEX %s.%s" % (
self.preparer.quote_identifier(drop.element.table.name),
- self.preparer.quote(
- self._index_identifier(drop.element.name),
- drop.element.quote)
+ self._prepared_index_name(drop.element,
+ include_schema=True)
)
def visit_create_index(self, create):
index = create.element
+ self._verify_index_table(index)
preparer = self.preparer
table = preparer.format_table(index.table)
- columns = [preparer.quote(c.name, c.quote) for c in index.columns]
+ columns = [self.sql_compiler.process(expr, include_table=False)
+ for expr in index.expressions]
+
name = preparer.quote(
- self._index_identifier(index.name),
+ self._prepared_index_name(index),
index.quote)
text = "CREATE "
def visit_drop_index(self, drop):
index = drop.element
- return "\nDROP INDEX %s ON %s" % \
- (self.preparer.quote(
- self._index_identifier(index.name), index.quote
- ),
+ return "\nDROP INDEX %s ON %s" % (
+ self._prepared_index_name(index,
+ include_schema=False),
self.preparer.format_table(index.table))
def visit_drop_constraint(self, drop):
def visit_create_index(self, create):
preparer = self.preparer
index = create.element
+ self._verify_index_table(index)
text = "CREATE "
if index.unique:
text += "UNIQUE "
- ops = index.kwargs.get('postgresql_ops', {})
text += "INDEX %s ON %s " % (
- preparer.quote(
- self._index_identifier(index.name), index.quote),
+ self._prepared_index_name(index,
+ include_schema=True),
preparer.format_table(index.table)
)
using = index.kwargs['postgresql_using']
text += "USING %s " % preparer.quote(using, index.quote)
+ ops = index.kwargs.get('postgresql_ops', {})
text += "(%s)" \
% (
', '.join([
- preparer.format_column(c) +
+ self.sql_compiler.process(expr, include_table=False) +
+
+
(c.key in ops and (' ' + ops[c.key]) or '')
- for c in index.columns])
+
+
+ for expr, c in zip(index.expressions, index.columns)])
)
- if "postgres_where" in index.kwargs:
- whereclause = index.kwargs['postgres_where']
- util.warn_deprecated(
- "The 'postgres_where' argument has been renamed "
- "to 'postgresql_where'.")
- elif 'postgresql_where' in index.kwargs:
+ if 'postgresql_where' in index.kwargs:
whereclause = index.kwargs['postgresql_where']
else:
whereclause = None
return preparer.format_table(table, use_schema=False)
def visit_create_index(self, create):
- index = create.element
- preparer = self.preparer
- text = "CREATE "
- if index.unique:
- text += "UNIQUE "
- text += "INDEX %s ON %s (%s)" \
- % (preparer.format_index(index,
- name=self._index_identifier(index.name)),
- preparer.format_table(index.table, use_schema=False),
- ', '.join(preparer.quote(c.name, c.quote)
- for c in index.columns))
- return text
+ return super(SQLiteDDLCompiler, self).\
+ visit_create_index(create, include_table_schema=False)
class SQLiteTypeCompiler(compiler.GenericTypeCompiler):
index = drop.element
return "\nDROP INDEX %s.%s" % (
self.preparer.quote_identifier(index.table.name),
- self.preparer.quote(
- self._index_identifier(index.name), index.quote)
+ self._prepared_index_name(drop.element,
+ include_schema=False)
)
:ref:`schema_indexes` - General information on :class:`.Index`.
- :ref:`postgresql_indexes` - PostgreSQL-specific options available for the :class:`.Index` construct.
+ :ref:`postgresql_indexes` - PostgreSQL-specific options available for the
+ :class:`.Index` construct.
+
+ :ref:`mysql_indexes` - MySQL-specific options available for the
+ :class:`.Index` construct.
- :ref:`mysql_indexes` - MySQL-specific options available for the :class:`.Index` construct.
"""
__visit_name__ = 'index'
- def __init__(self, name, *columns, **kw):
+ def __init__(self, name, *expressions, **kw):
"""Construct an index object.
:param name:
The name of the index
- :param \*columns:
- Columns to include in the index. All columns must belong to the same
- table.
+ :param \*expressions:
+ Column expressions to include in the index. The expressions
+ are normally instances of :class:`.Column`, but may also
+ be arbitrary SQL expressions which ultmately refer to a
+ :class:`.Column`.
+
+ .. versionadded:: 0.8 :class:`.Index` supports SQL expressions as
+ well as plain columns.
:param unique:
Defaults to False: create a unique index.
"""
self.table = None
+
+ columns = []
+ for expr in expressions:
+ if not isinstance(expr, expression.ClauseElement):
+ columns.append(expr)
+ else:
+ cols = []
+ visitors.traverse(expr, {}, {'column': cols.append})
+ if cols:
+ columns.append(cols[0])
+ else:
+ columns.append(expr)
+
+ self.expressions = expressions
+
# will call _set_parent() if table-bound column
# objects are present
ColumnCollectionMixin.__init__(self, *columns)
+
self.name = name
self.unique = kw.pop('unique', False)
self.kwargs = kw
)
table.indexes.add(self)
+ self.expressions = [
+ expr if isinstance(expr, expression.ClauseElement)
+ else colexpr
+ for expr, colexpr in zip(self.expressions, self.columns)
+ ]
+
@property
def bind(self):
"""Return the connectable associated with this Index."""
def visit_drop_view(self, drop):
return "\nDROP VIEW " + self.preparer.format_table(drop.element)
- def _index_identifier(self, ident):
- if isinstance(ident, sql._truncated_label):
- max = self.dialect.max_index_name_length or \
- self.dialect.max_identifier_length
- if len(ident) > max:
- ident = ident[0:max - 8] + \
- "_" + util.md5_hex(ident)[-4:]
- else:
- self.dialect.validate_identifier(ident)
- return ident
+ def _verify_index_table(self, index):
+ if index.table is None:
+ raise exc.CompileError("Index '%s' is not associated "
+ "with any table." % index.name)
+
- def visit_create_index(self, create, include_schema=False):
+ def visit_create_index(self, create, include_schema=False,
+ include_table_schema=True):
index = create.element
+ self._verify_index_table(index)
preparer = self.preparer
text = "CREATE "
if index.unique:
% (
self._prepared_index_name(index,
include_schema=include_schema),
- preparer.format_table(index.table),
- ', '.join(preparer.quote(c.name, c.quote)
- for c in index.columns))
+ preparer.format_table(index.table,
+ use_schema=include_table_schema),
+ ', '.join(
+ self.sql_compiler.process(expr,
+ include_table=False) for
+ expr in index.expressions)
+ )
return text
def visit_drop_index(self, drop):
else:
schema_name = None
+ ident = index.name
+ if isinstance(ident, sql._truncated_label):
+ max_ = self.dialect.max_index_name_length or \
+ self.dialect.max_identifier_length
+ if len(ident) > max_:
+ ident = ident[0:max_ - 8] + \
+ "_" + util.md5_hex(ident)[-4:]
+ else:
+ self.dialect.validate_identifier(ident)
+
index_name = self.preparer.quote(
- self._index_identifier(index.name),
+ ident,
index.quote)
if schema_name:
)
)
+ @testing.provide_metadata
+ def test_index_functional_create(self):
+ metadata = self.metadata
+
+ t = Table('sometable', metadata,
+ Column('id', Integer, primary_key=True),
+ Column('data', String(50))
+ )
+ Index('myindex', t.c.data.desc())
+ self.assert_sql_execution(
+ testing.db,
+ lambda: t.create(testing.db),
+ CompiledSQL('CREATE TABLE sometable (id INTEGER NOT NULL, '
+ 'data VARCHAR(50), PRIMARY KEY (id))'),
+ ExactSQL('CREATE INDEX myindex ON sometable (data DESC)')
+ )
+
class ConstraintCompilationTest(fixtures.TestBase, AssertsCompiledSQL):
__dialect__ = 'default'
dialect=dialect
)
+ def test_functional_index(self):
+ metadata = MetaData()
+ x = Table('x', metadata,
+ Column('q', String(50))
+ )
+ idx = Index('y', func.lower(x.c.q))
+
+ self.assert_compile(
+ schema.CreateIndex(idx),
+ "CREATE INDEX y ON x (lower(q))"
+ )
+
+ self.assert_compile(
+ schema.CreateIndex(idx),
+ "CREATE INDEX y ON x (lower(q))",
+ dialect=testing.db.dialect
+ )
+
def test_index_declaration_inline(self):
metadata = MetaData()
Index, "foo", 5
)
+ def test_raise_expr_no_column(self):
+ idx = Index('foo', func.lower(5))
+
+ assert_raises_message(
+ exc.CompileError,
+ "Index 'foo' is not associated with any table.",
+ schema.CreateIndex(idx).compile, dialect=testing.db.dialect
+ )
+ assert_raises_message(
+ exc.CompileError,
+ "Index 'foo' is not associated with any table.",
+ schema.CreateIndex(idx).compile
+ )
+
+
def test_no_warning_w_no_columns(self):
- Index(name="foo")
+ # I think the test here is, there is no warning.
+ # people want to create empty indexes for the purpose of
+ # a drop.
+ idx = Index(name="foo")
+
+ assert_raises_message(
+ exc.CompileError,
+ "Index 'foo' is not associated with any table.",
+ schema.CreateIndex(idx).compile, dialect=testing.db.dialect
+ )
+ assert_raises_message(
+ exc.CompileError,
+ "Index 'foo' is not associated with any table.",
+ schema.CreateIndex(idx).compile
+ )
def test_raise_clauseelement_not_a_column(self):
m = MetaData()