From: Mike Bayer Date: Thu, 17 Jan 2013 02:04:32 +0000 (-0500) Subject: :class:`.Index` now supports arbitrary SQL expressions and/or X-Git-Tag: rel_0_8_0~31^2~3 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=7fedf9958687222a9e3c2fc4d50983711dbb3d52;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git :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. [ticket:695] --- diff --git a/doc/build/changelog/changelog_08.rst b/doc/build/changelog/changelog_08.rst index 3abac50258..7d6035a6d4 100644 --- a/doc/build/changelog/changelog_08.rst +++ b/doc/build/changelog/changelog_08.rst @@ -6,6 +6,16 @@ .. 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 diff --git a/doc/build/core/schema.rst b/doc/build/core/schema.rst index 2c47f56471..7771e3e4df 100644 --- a/doc/build/core/schema.rst +++ b/doc/build/core/schema.rst @@ -1170,6 +1170,30 @@ The :class:`~sqlalchemy.schema.Index` object also supports its own ``create()`` {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: diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index d7c29654a3..58ed65bc9b 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -935,9 +935,8 @@ class MSDDLCompiler(compiler.DDLCompiler): 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) ) diff --git a/lib/sqlalchemy/dialects/mysql/base.py b/lib/sqlalchemy/dialects/mysql/base.py index 6e09a359ee..6bc9bd4a49 100644 --- a/lib/sqlalchemy/dialects/mysql/base.py +++ b/lib/sqlalchemy/dialects/mysql/base.py @@ -1513,11 +1513,14 @@ class MySQLDDLCompiler(compiler.DDLCompiler): 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 " @@ -1550,10 +1553,9 @@ class MySQLDDLCompiler(compiler.DDLCompiler): 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): diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index 81d2079c05..afbb23e154 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -962,13 +962,13 @@ class PGDDLCompiler(compiler.DDLCompiler): 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) ) @@ -976,20 +976,20 @@ class PGDDLCompiler(compiler.DDLCompiler): 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 diff --git a/lib/sqlalchemy/dialects/sqlite/base.py b/lib/sqlalchemy/dialects/sqlite/base.py index 241d0bcdfc..7558accccd 100644 --- a/lib/sqlalchemy/dialects/sqlite/base.py +++ b/lib/sqlalchemy/dialects/sqlite/base.py @@ -522,18 +522,8 @@ class SQLiteDDLCompiler(compiler.DDLCompiler): 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): diff --git a/lib/sqlalchemy/dialects/sybase/base.py b/lib/sqlalchemy/dialects/sybase/base.py index 33a0c445bf..a9e5c5fda0 100644 --- a/lib/sqlalchemy/dialects/sybase/base.py +++ b/lib/sqlalchemy/dialects/sybase/base.py @@ -412,8 +412,8 @@ class SybaseDDLCompiler(compiler.DDLCompiler): 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) ) diff --git a/lib/sqlalchemy/schema.py b/lib/sqlalchemy/schema.py index b5e97802d8..5cb592857f 100644 --- a/lib/sqlalchemy/schema.py +++ b/lib/sqlalchemy/schema.py @@ -2344,22 +2344,30 @@ class Index(ColumnCollectionMixin, SchemaItem): :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. @@ -2369,9 +2377,25 @@ class Index(ColumnCollectionMixin, SchemaItem): """ 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 @@ -2397,6 +2421,12 @@ class Index(ColumnCollectionMixin, SchemaItem): ) 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.""" diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index 127de1dfaf..152e68e34f 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -1933,20 +1933,17 @@ class DDLCompiler(engine.Compiled): 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: @@ -1955,9 +1952,13 @@ class DDLCompiler(engine.Compiled): % ( 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): @@ -1973,8 +1974,18 @@ class DDLCompiler(engine.Compiled): 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: diff --git a/test/sql/test_constraints.py b/test/sql/test_constraints.py index 036a388bbd..ab294e1ebb 100644 --- a/test/sql/test_constraints.py +++ b/test/sql/test_constraints.py @@ -297,6 +297,23 @@ class ConstraintGenTest(fixtures.TestBase, AssertsExecutionResults): ) ) + @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' @@ -373,6 +390,24 @@ class ConstraintCompilationTest(fixtures.TestBase, AssertsCompiledSQL): 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() @@ -819,8 +854,37 @@ class ConstraintAPITest(fixtures.TestBase): 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()