:ticket:`4753`
+.. _change_4449:
+
+Improved column labeling for simple column expressions using CAST or similar
+----------------------------------------------------------------------------
+
+A user pointed out that the PostgreSQL database has a convenient behavior when
+using functions like CAST against a named column, in that the result column name
+is named the same as the inner expression::
+
+ test=> SELECT CAST(data AS VARCHAR) FROM foo;
+
+ data
+ ------
+ 5
+ (1 row)
+
+This allows one to apply CAST to table columns while not losing the column
+name (above using the name ``"data"``) in the result row. Compare to
+databases such as MySQL/MariaDB, as well as most others, where the column
+name is taken from the full SQL expression and is not very portable::
+
+ MariaDB [test]> SELECT CAST(data AS CHAR) FROM foo;
+ +--------------------+
+ | CAST(data AS CHAR) |
+ +--------------------+
+ | 5 |
+ +--------------------+
+ 1 row in set (0.003 sec)
+
+
+In SQLAlchemy Core expressions, we never deal with a raw generated name like
+the above, as SQLAlchemy applies auto-labeling to expressions like these, which
+are up until now always a so-called "anonymous" expression::
+
+ >>> print(select([cast(foo.c.data, String)]))
+ SELECT CAST(foo.data AS VARCHAR) AS anon_1 # old behavior
+ FROM foo
+
+These anonymous expressions were necessary as SQLAlchemy's
+:class:`.ResultProxy` made heavy use of result column names in order to match
+up datatypes, such as the :class:`.String` datatype which used to have
+result-row-processing behavior, to the correct column, so most importantly the
+names had to be both easy to determine in a database-agnostic manner as well as
+unique in all cases. In SQLAlchemy 1.0 as part of :ticket:`918`, this
+reliance on named columns in result rows (specifically the
+``cursor.description`` element of the PEP-249 cursor) was scaled back to not be
+necessary for most Core SELECT constructs; in release 1.4, the system overall
+is becoming more comfortable with SELECT statements that have duplicate column
+or label names such as in :ref:`change_4753`. So we now emulate PostgreSQL's
+reasonable behavior for simple modifications to a single column, most
+prominently with CAST::
+
+ >>> print(select([cast(foo.c.data, String)]))
+ SELECT CAST(foo.data AS VARCHAR) AS data
+ FROM foo
+
+For CAST against expressions that don't have a name, the previous logic is used
+to generate the usual "anonymous" labels::
+
+ >>> print(select([cast('hi there,' + foo.c.data, String)]))
+ SELECT CAST(:data_1 + foo.data AS VARCHAR) AS anon_1
+ FROM foo
+
+A :func:`.cast` against a :class:`.Label`, despite having to omit the label
+expression as these don't render inside of a CAST, will nonetheless make use of
+the given name::
+
+ >>> print(select([cast(('hi there,' + foo.c.data).label('hello_data'), String)]))
+ SELECT CAST(:data_1 + foo.data AS VARCHAR) AS hello_data
+ FROM foo
+
+And of course as was always the case, :class:`.Label` can be applied to the
+expression on the outside to apply an "AS <name>" label directly::
+
+ >>> print(select([cast(('hi there,' + foo.c.data), String).label('hello_data')]))
+ SELECT CAST(:data_1 + foo.data AS VARCHAR) AS hello_data
+ FROM foo
+
+
+:ticket:`4449`
+
.. _change_4712:
Connection-level transactions can now be inactive based on subtransaction
--- /dev/null
+.. change::
+ :tags: usecase, sql
+ :tickets: 4449
+
+ Additional logic has been added such that certain SQL expressions which
+ typically wrap a single database column will use the name of that column as
+ their "anonymous label" name within a SELECT statement, potentially making
+ key-based lookups in result tuples more intutive. The primary example of
+ this is that of a CAST expression, e.g. ``CAST(table.colname AS INTEGER)``,
+ which will export its default name as "colname", rather than the usual
+ "anon_1" label, that is, ``CAST(table.colname AS INTEGER) AS colname``.
+ If the inner expression doesn't have a name, then the previous "anonymous
+ label" logic is used. When using SELECT statements that make use of
+ :meth:`.Select.apply_labels`, such as those emitted by the ORM, the
+ labeling logic will produce ``<tablename>_<inner column name>`` in the same
+ was as if the column were named alone. The logic applies right now to the
+ :func:`.cast` and :func:`.type_coerce` constructs as well as some
+ single-element boolean expressions.
+
+ .. seealso::
+
+ :ref:`change_4449`
\ No newline at end of file
.. autoclass:: WithinGroup
:members:
+.. autoclass:: WrapsColumnExpression
+ :members:
+
.. autoclass:: sqlalchemy.sql.elements.True_
:members:
>>> from sqlalchemy import cast
>>> s = select([cast(users.c.id, String)])
>>> conn.execute(s).fetchall()
- {opensql}SELECT CAST(users.id AS VARCHAR) AS anon_1
+ {opensql}SELECT CAST(users.id AS VARCHAR) AS id
FROM users
()
{stop}[('1',), ('2',)]
return self._anon_label(getattr(self, "_label", None))
+class WrapsColumnExpression(object):
+ """Mixin that defines a :class:`.ColumnElement` as a wrapper with special
+ labeling behavior for an expression that already has a name.
+
+ .. versionadded:: 1.4
+
+ .. seealso::
+
+ :ref:`change_4449`
+
+
+ """
+
+ @property
+ def wrapped_column_expression(self):
+ raise NotImplementedError()
+
+ @property
+ def _label(self):
+ wce = self.wrapped_column_expression
+ if hasattr(wce, "_label"):
+ return wce._label
+ else:
+ return None
+
+ @property
+ def anon_label(self):
+ wce = self.wrapped_column_expression
+ if hasattr(wce, "name"):
+ return wce.name
+ elif hasattr(wce, "anon_label"):
+ return wce.anon_label
+ else:
+ return super(WrapsColumnExpression, self).anon_label
+
+
class BindParameter(roles.InElementRole, ColumnElement):
r"""Represent a "bound expression".
return ColumnClause(text, type_=type_, is_literal=True)
-class Cast(ColumnElement):
+class Cast(WrapsColumnExpression, ColumnElement):
"""Represent a ``CAST`` expression.
:class:`.Cast` is produced using the :func:`.cast` factory function,
def _from_objects(self):
return self.clause._from_objects
+ @property
+ def wrapped_column_expression(self):
+ return self.clause
+
-class TypeCoerce(ColumnElement):
+class TypeCoerce(WrapsColumnExpression, ColumnElement):
"""Represent a Python-side type-coercion wrapper.
:class:`.TypeCoerce` supplies the :func:`.expression.type_coerce`
else:
return self.clause
+ @property
+ def wrapped_column_expression(self):
+ return self.clause
+
class Extract(ColumnElement):
"""Represent a SQL EXTRACT clause, ``extract(field FROM expr)``."""
)
-class AsBoolean(UnaryExpression):
+class AsBoolean(WrapsColumnExpression, UnaryExpression):
def __init__(self, element, operator, negate):
self.element = element
self.type = type_api.BOOLEANTYPE
self.wraps_column_expression = True
self._is_implicitly_boolean = element._is_implicitly_boolean
+ @property
+ def wrapped_column_expression(self):
+ return self.element
+
def self_group(self, against=None):
# type: (Optional[Any]) -> ClauseElement
return self
self.assert_compile(
select([try_cast(t1.c.id, Integer)]),
- "SELECT TRY_CAST (t1.id AS INTEGER) AS anon_1 FROM t1",
+ "SELECT TRY_CAST (t1.id AS INTEGER) AS id FROM t1",
)
str(sel),
"SELECT casttest.id, casttest.v1, casttest.v2, "
"casttest.ts, "
- "CAST(casttest.v1 AS DECIMAL) AS anon_1 \nFROM casttest",
+ "CAST(casttest.v1 AS DECIMAL) AS v1 \nFROM casttest",
)
else:
eq_(
str(sel),
"SELECT casttest.id, casttest.v1, casttest.v2, "
"casttest.ts, CAST(casttest.v1 AS NUMERIC) AS "
- "anon_1 \nFROM casttest",
+ "v1 \nFROM casttest",
)
# first test with PostgreSQL engine
exprs[2],
str(exprs[2]),
"CAST(mytable.name AS NUMERIC)",
- "anon_1",
+ "name", # due to [ticket:4449]
),
(t1.c.col1, "col1", "mytable.col1", None),
(
eq_ignore_whitespace(
str(stmt),
- "SELECT CAST(mytable.myid AS MyType) AS anon_1 FROM mytable",
+ "SELECT CAST(mytable.myid AS MyType) AS myid FROM mytable",
)
def test_within_group(self):
def test_label_plus_element(self):
t = Table("t", MetaData(), Column("a", Integer))
l1 = t.c.a.label("bar")
- tc = type_coerce(t.c.a, String)
+ tc = type_coerce(t.c.a + "str", String)
stmt = select([t.c.a, l1, tc])
comp = stmt.compile()
tc_anon_label = comp._create_result_map()["anon_1"][1][0]
"a": ("a", (t.c.a, "a", "a"), t.c.a.type),
"bar": ("bar", (l1, "bar"), l1.type),
"anon_1": (
- "%%(%d anon)s" % id(tc),
+ tc.anon_label,
(tc_anon_label, "anon_1", tc),
tc.type,
),
from sqlalchemy import bindparam
+from sqlalchemy import Boolean
+from sqlalchemy import cast
from sqlalchemy import exc as exceptions
from sqlalchemy import Integer
from sqlalchemy import MetaData
from sqlalchemy import or_
from sqlalchemy import select
+from sqlalchemy import String
+from sqlalchemy import type_coerce
from sqlalchemy.engine import default
+from sqlalchemy.ext.compiler import compiles
+from sqlalchemy.sql import coercions
from sqlalchemy.sql import column
+from sqlalchemy.sql import roles
from sqlalchemy.sql import table
from sqlalchemy.sql.elements import _truncated_label
+from sqlalchemy.sql.elements import ColumnElement
+from sqlalchemy.sql.elements import WrapsColumnExpression
from sqlalchemy.testing import assert_raises
from sqlalchemy.testing import AssertsCompiledSQL
from sqlalchemy.testing import engines
set(compiled._create_result_map()),
set(["tablename_columnn_1", "tablename_columnn_2"]),
)
+
+
+class ColExprLabelTest(fixtures.TestBase, AssertsCompiledSQL):
+ """Test the :class:`.WrapsColumnExpression` mixin, which provides
+ auto-labels that match a named expression
+
+ """
+
+ __dialect__ = "default"
+
+ table1 = table("some_table", column("name"), column("value"))
+
+ def _fixture(self):
+ class SomeColThing(WrapsColumnExpression, ColumnElement):
+ def __init__(self, expression):
+ self.clause = coercions.expect(
+ roles.ExpressionElementRole, expression
+ )
+
+ @property
+ def wrapped_column_expression(self):
+ return self.clause
+
+ @compiles(SomeColThing)
+ def process(element, compiler, **kw):
+ return "SOME_COL_THING(%s)" % compiler.process(
+ element.clause, **kw
+ )
+
+ return SomeColThing
+
+ def test_column_auto_label_dupes(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ table1.c.name,
+ table1.c.name,
+ expr(table1.c.name),
+ expr(table1.c.name),
+ ]
+ ),
+ "SELECT some_table.name, some_table.name, "
+ "SOME_COL_THING(some_table.name) AS name, "
+ "SOME_COL_THING(some_table.name) AS name FROM some_table",
+ )
+
+ def test_anon_expression_fallback(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select([table1.c.name + "foo", expr(table1.c.name + "foo")]),
+ "SELECT some_table.name || :name_1 AS anon_1, "
+ "SOME_COL_THING(some_table.name || :name_2) AS anon_2 "
+ "FROM some_table",
+ )
+
+ def test_anon_expression_fallback_use_labels(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [table1.c.name + "foo", expr(table1.c.name + "foo")]
+ ).apply_labels(),
+ "SELECT some_table.name || :name_1 AS anon_1, "
+ "SOME_COL_THING(some_table.name || :name_2) AS anon_2 "
+ "FROM some_table",
+ )
+
+ def test_label_auto_label(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ expr(table1.c.name.label("foo")),
+ table1.c.name.label("bar"),
+ table1.c.value,
+ ]
+ ),
+ "SELECT SOME_COL_THING(some_table.name) AS foo, "
+ "some_table.name AS bar, some_table.value FROM some_table",
+ )
+
+ def test_cast_auto_label(self):
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ cast(table1.c.name, Integer),
+ cast(table1.c.name, String),
+ table1.c.name,
+ ]
+ ),
+ "SELECT CAST(some_table.name AS INTEGER) AS name, "
+ "CAST(some_table.name AS VARCHAR) AS name, "
+ "some_table.name FROM some_table",
+ )
+
+ def test_type_coerce_auto_label(self):
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ type_coerce(table1.c.name, Integer),
+ type_coerce(table1.c.name, String),
+ table1.c.name,
+ ]
+ ),
+ # ideally type_coerce wouldn't label at all...
+ "SELECT some_table.name AS name, "
+ "some_table.name AS name, "
+ "some_table.name FROM some_table",
+ )
+
+ def test_boolean_auto_label(self):
+ col = column("value", Boolean)
+
+ self.assert_compile(
+ select([~col, col]),
+ # not sure if this SQL is right but this is what it was
+ # before the new labeling, just different label name
+ "SELECT value = 0 AS value, value",
+ )
+
+ def test_label_auto_label_use_labels(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ expr(table1.c.name.label("foo")),
+ table1.c.name.label("bar"),
+ table1.c.value,
+ ]
+ ).apply_labels(),
+ # the expr around label is treated the same way as plain column
+ # with label
+ "SELECT SOME_COL_THING(some_table.name) AS foo, "
+ "some_table.name AS bar, "
+ "some_table.value AS some_table_value FROM some_table",
+ )
+
+ def test_column_auto_label_dupes_use_labels(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select(
+ [
+ table1.c.name,
+ table1.c.name,
+ expr(table1.c.name),
+ expr(table1.c.name),
+ ]
+ ).apply_labels(),
+ "SELECT some_table.name AS some_table_name, "
+ "some_table.name AS some_table_name_1, "
+ "SOME_COL_THING(some_table.name) AS some_table_name_2, "
+ "SOME_COL_THING(some_table.name) AS some_table_name_3 "
+ "FROM some_table",
+ )
+
+ def test_column_auto_label_use_labels(self):
+ expr = self._fixture()
+ table1 = self.table1
+
+ self.assert_compile(
+ select([table1.c.name, expr(table1.c.value)]).apply_labels(),
+ "SELECT some_table.name AS some_table_name, "
+ "SOME_COL_THING(some_table.value) "
+ "AS some_table_value FROM some_table",
+ )
table = self._fixture()
self.assert_compile(
select([cast(table.c.y, String)]),
- "SELECT CAST(test_table.y AS VARCHAR) AS anon_1 FROM test_table",
+ "SELECT CAST(test_table.y AS VARCHAR) AS y FROM test_table",
)
def test_select_cols_use_labels(self):
t.insert().values(data=coerce_fn("d1", MyType)).execute()
eq_(
- select([t.c.data, coerce_fn(t.c.data, MyType)])
+ select([t.c.data.label("x"), coerce_fn(t.c.data, MyType)])
.alias()
.select()
.execute()