From: Nick Crews Date: Thu, 18 May 2023 12:01:18 +0000 (-0400) Subject: Move try_cast() from mssql to base X-Git-Tag: rel_2_0_14~1^2 X-Git-Url: http://git.ipfire.org/?a=commitdiff_plain;h=be614e7a4e87054ff8d696ee7a3c496458f20b32;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Move try_cast() from mssql to base Generalized the MSSQL :func:`_sql.try_cast` function into the ``sqlalchemy.`` import namespace so that it may be implemented by third party dialects as well. Within SQLAlchemy, the :func:`_sql.try_cast` function remains a SQL Server-only construct that will raise :class:`.CompileError` if used with backends that don't support it. :func:`_sql.try_cast` implements a CAST where un-castable conversions are returned as NULL, instead of raising an error. Theoretically, the construct could be implemented by third party dialects for Google BigQuery, DuckDB, and Snowflake, and possibly others. Pull request courtesy Nick Crews. Fixes: #9752 Closes: #9753 Pull-request: https://github.com/sqlalchemy/sqlalchemy/pull/9753 Pull-request-sha: 2e81b8d2c9314ca2cc5807fc807c35fefbe6ad2c Change-Id: Ib57999b5947a2e34d5d305e294ff99dc08b01111 --- diff --git a/doc/build/changelog/unreleased_20/9752.rst b/doc/build/changelog/unreleased_20/9752.rst new file mode 100644 index 0000000000..7f199280e3 --- /dev/null +++ b/doc/build/changelog/unreleased_20/9752.rst @@ -0,0 +1,17 @@ +.. change:: + :tags: usecase, sql + :tickets: 9752 + + + Generalized the MSSQL :func:`_sql.try_cast` function into the + ``sqlalchemy.`` import namespace so that it may be implemented by third + party dialects as well. Within SQLAlchemy, the :func:`_sql.try_cast` + function remains a SQL Server-only construct that will raise + :class:`.CompileError` if used with backends that don't support it. + + :func:`_sql.try_cast` implements a CAST where un-castable conversions are + returned as NULL, instead of raising an error. Theoretically, the construct + could be implemented by third party dialects for Google BigQuery, DuckDB, + and Snowflake, and possibly others. + + Pull request courtesy Nick Crews. diff --git a/doc/build/core/sqlelement.rst b/doc/build/core/sqlelement.rst index 23dd2118b0..e2174a2c84 100644 --- a/doc/build/core/sqlelement.rst +++ b/doc/build/core/sqlelement.rst @@ -63,6 +63,8 @@ used when building up SQLAlchemy Expression Language constructs. .. autofunction:: true +.. autofunction:: try_cast + .. autofunction:: tuple_ .. autofunction:: type_coerce @@ -200,6 +202,9 @@ The classes here are generated using the constructors listed at .. autoclass:: TextClause :members: +.. autoclass:: TryCast + :members: + .. autoclass:: Tuple :members: diff --git a/lib/sqlalchemy/__init__.py b/lib/sqlalchemy/__init__.py index 9616f4d64a..b8dab006fc 100644 --- a/lib/sqlalchemy/__init__.py +++ b/lib/sqlalchemy/__init__.py @@ -199,6 +199,8 @@ from .sql.expression import TextClause as TextClause from .sql.expression import TextualSelect as TextualSelect from .sql.expression import true as true from .sql.expression import True_ as True_ +from .sql.expression import try_cast as try_cast +from .sql.expression import TryCast as TryCast from .sql.expression import Tuple as Tuple from .sql.expression import tuple_ as tuple_ from .sql.expression import type_coerce as type_coerce diff --git a/lib/sqlalchemy/dialects/mssql/__init__.py b/lib/sqlalchemy/dialects/mssql/__init__.py index 3bbfad344c..3f70847768 100644 --- a/lib/sqlalchemy/dialects/mssql/__init__.py +++ b/lib/sqlalchemy/dialects/mssql/__init__.py @@ -6,7 +6,6 @@ # the MIT License: https://www.opensource.org/licenses/mit-license.php # mypy: ignore-errors - from . import base # noqa from . import pymssql # noqa from . import pyodbc # noqa @@ -39,11 +38,11 @@ from .base import TEXT from .base import TIME from .base import TIMESTAMP from .base import TINYINT -from .base import try_cast from .base import UNIQUEIDENTIFIER from .base import VARBINARY from .base import VARCHAR from .base import XML +from ...sql import try_cast base.dialect = dialect = pyodbc.dialect diff --git a/lib/sqlalchemy/dialects/mssql/base.py b/lib/sqlalchemy/dialects/mssql/base.py index aa319e2393..3fd683172e 100644 --- a/lib/sqlalchemy/dialects/mssql/base.py +++ b/lib/sqlalchemy/dialects/mssql/base.py @@ -938,9 +938,11 @@ from ...sql import func from ...sql import quoted_name from ...sql import roles from ...sql import sqltypes +from ...sql import try_cast as try_cast # noqa: F401 from ...sql import util as sql_util from ...sql._typing import is_sql_compiler from ...sql.compiler import InsertmanyvaluesSentinelOpts +from ...sql.elements import TryCast as TryCast # noqa: F401 from ...types import BIGINT from ...types import BINARY from ...types import CHAR @@ -1603,41 +1605,6 @@ class SQL_VARIANT(sqltypes.TypeEngine): __visit_name__ = "SQL_VARIANT" -def try_cast(*arg, **kw): - """Create a TRY_CAST expression. - - :class:`.TryCast` is a subclass of SQLAlchemy's :class:`.Cast` - construct, and works in the same way, except that the SQL expression - rendered is "TRY_CAST" rather than "CAST":: - - from sqlalchemy import select - from sqlalchemy import Numeric - from sqlalchemy.dialects.mssql import try_cast - - stmt = select( - try_cast(product_table.c.unit_price, Numeric(10, 4)) - ) - - The above would render:: - - SELECT TRY_CAST (product_table.unit_price AS NUMERIC(10, 4)) - FROM product_table - - .. versionadded:: 1.3.7 - - """ - return TryCast(*arg, **kw) - - -class TryCast(sql.elements.Cast): - """Represent a SQL Server TRY_CAST expression.""" - - __visit_name__ = "try_cast" - - stringify_dialect = "mssql" - inherit_cache = True - - # old names. MSDateTime = _MSDateTime MSDate = _MSDate diff --git a/lib/sqlalchemy/sql/__init__.py b/lib/sqlalchemy/sql/__init__.py index 96cffed7d0..c4c8c7d27a 100644 --- a/lib/sqlalchemy/sql/__init__.py +++ b/lib/sqlalchemy/sql/__init__.py @@ -93,6 +93,7 @@ from .expression import tablesample as tablesample from .expression import text as text from .expression import true as true from .expression import True_ as True_ +from .expression import try_cast as try_cast from .expression import tuple_ as tuple_ from .expression import type_coerce as type_coerce from .expression import union as union diff --git a/lib/sqlalchemy/sql/_elements_constructors.py b/lib/sqlalchemy/sql/_elements_constructors.py index 99a839cc90..27197375d2 100644 --- a/lib/sqlalchemy/sql/_elements_constructors.py +++ b/lib/sqlalchemy/sql/_elements_constructors.py @@ -40,6 +40,7 @@ from .elements import Null from .elements import Over from .elements import TextClause from .elements import True_ +from .elements import TryCast from .elements import Tuple from .elements import TypeCoerce from .elements import UnaryExpression @@ -893,6 +894,10 @@ def cast( :ref:`tutorial_casts` + :func:`.try_cast` - an alternative to CAST that results in + NULLs when the cast fails, instead of raising an error. + Only supported by some dialects. + :func:`.type_coerce` - an alternative to CAST that coerces the type on the Python side only, which is often sufficient to generate the correct SQL and data coercion. @@ -902,6 +907,49 @@ def cast( return Cast(expression, type_) +def try_cast( + expression: _ColumnExpressionOrLiteralArgument[Any], + type_: _TypeEngineArgument[_T], +) -> TryCast[_T]: + """Produce a ``TRY_CAST`` expression for backends which support it; + this is a ``CAST`` which returns NULL for un-castable conversions. + + In SQLAlchemy, this construct is supported **only** by the SQL Server + dialect, and will raise a :class:`.CompileError` if used on other + included backends. However, third party backends may also support + this construct. + + .. tip:: As :func:`_sql.try_cast` originates from the SQL Server dialect, + it's importable both from ``sqlalchemy.`` as well as from + ``sqlalchemy.dialects.mssql``. + + :func:`_sql.try_cast` returns an instance of :class:`.TryCast` and + generally behaves similarly to the :class:`.Cast` construct; + at the SQL level, the difference between ``CAST`` and ``TRY_CAST`` + is that ``TRY_CAST`` returns NULL for an un-castable expression, + such as attempting to cast a string ``"hi"`` to an integer value. + + E.g.:: + + from sqlalchemy import select, try_cast, Numeric + + stmt = select( + try_cast(product_table.c.unit_price, Numeric(10, 4)) + ) + + The above would render on Microsoft SQL Server as:: + + SELECT TRY_CAST (product_table.unit_price AS NUMERIC(10, 4)) + FROM product_table + + .. versionadded:: 2.0.14 :func:`.try_cast` has been + generalized from the SQL Server dialect into a general use + construct that may be supported by additional dialects. + + """ + return TryCast(expression, type_) + + def column( text: str, type_: Optional[_TypeEngineArgument[_T]] = None, diff --git a/lib/sqlalchemy/sql/compiler.py b/lib/sqlalchemy/sql/compiler.py index ad686ce27e..d4809ef934 100644 --- a/lib/sqlalchemy/sql/compiler.py +++ b/lib/sqlalchemy/sql/compiler.py @@ -6393,6 +6393,12 @@ class StrSQLCompiler(SQLCompiler): replacement._compiler_dispatch(self, **kw), ) + def visit_try_cast(self, cast, **kwargs): + return "TRY_CAST(%s AS %s)" % ( + cast.clause._compiler_dispatch(self, **kwargs), + cast.typeclause._compiler_dispatch(self, **kwargs), + ) + class DDLCompiler(Compiled): is_ddl = True diff --git a/lib/sqlalchemy/sql/elements.py b/lib/sqlalchemy/sql/elements.py index 2e32da7540..884e2b90fe 100644 --- a/lib/sqlalchemy/sql/elements.py +++ b/lib/sqlalchemy/sql/elements.py @@ -3372,6 +3372,8 @@ class Cast(WrapsColumnExpression[_T]): :func:`.cast` + :func:`.try_cast` + :func:`.type_coerce` - an alternative to CAST that coerces the type on the Python side only, which is often sufficient to generate the correct SQL and data coercion. @@ -3412,6 +3414,22 @@ class Cast(WrapsColumnExpression[_T]): return self.clause +class TryCast(Cast[_T]): + """Represent a TRY_CAST expression. + + Details on :class:`.TryCast` usage is at :func:`.try_cast`. + + .. seealso:: + + :func:`.try_cast` + + :ref:`tutorial_casts` + """ + + __visit_name__ = "try_cast" + inherit_cache = True + + class TypeCoerce(WrapsColumnExpression[_T]): """Represent a Python-side type-coercion wrapper. diff --git a/lib/sqlalchemy/sql/expression.py b/lib/sqlalchemy/sql/expression.py index f1cb4c276a..b25fb50d40 100644 --- a/lib/sqlalchemy/sql/expression.py +++ b/lib/sqlalchemy/sql/expression.py @@ -42,6 +42,7 @@ from ._elements_constructors import outparam as outparam from ._elements_constructors import over as over from ._elements_constructors import text as text from ._elements_constructors import true as true +from ._elements_constructors import try_cast as try_cast from ._elements_constructors import tuple_ as tuple_ from ._elements_constructors import type_coerce as type_coerce from ._elements_constructors import within_group as within_group @@ -100,6 +101,7 @@ from .elements import SavepointClause as SavepointClause from .elements import SQLColumnExpression as SQLColumnExpression from .elements import TextClause as TextClause from .elements import True_ as True_ +from .elements import TryCast as TryCast from .elements import Tuple as Tuple from .elements import TypeClause as TypeClause from .elements import TypeCoerce as TypeCoerce diff --git a/test/dialect/mssql/test_compiler.py b/test/dialect/mssql/test_compiler.py index 0076c76fd9..93edbd9cb9 100644 --- a/test/dialect/mssql/test_compiler.py +++ b/test/dialect/mssql/test_compiler.py @@ -20,12 +20,12 @@ from sqlalchemy import String from sqlalchemy import Table from sqlalchemy import testing from sqlalchemy import text +from sqlalchemy import try_cast from sqlalchemy import union from sqlalchemy import UniqueConstraint from sqlalchemy import update from sqlalchemy.dialects import mssql from sqlalchemy.dialects.mssql import base as mssql_base -from sqlalchemy.dialects.mssql.base import try_cast from sqlalchemy.sql import column from sqlalchemy.sql import quoted_name from sqlalchemy.sql import table @@ -1473,12 +1473,17 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): "CREATE INDEX foo ON test (x) INCLUDE (y) WHERE y > 1", ) - def test_try_cast(self): - metadata = MetaData() - t1 = Table("t1", metadata, Column("id", Integer, primary_key=True)) + @testing.variation("use_mssql_version", [True, False]) + def test_try_cast(self, use_mssql_version): + t1 = Table("t1", MetaData(), Column("id", Integer, primary_key=True)) + + if use_mssql_version: + stmt = select(mssql.try_cast(t1.c.id, Integer)) + else: + stmt = select(try_cast(t1.c.id, Integer)) self.assert_compile( - select(try_cast(t1.c.id, Integer)), + stmt, "SELECT TRY_CAST (t1.id AS INTEGER) AS id FROM t1", ) diff --git a/test/sql/test_compiler.py b/test/sql/test_compiler.py index 4d0864af9e..648056cde5 100644 --- a/test/sql/test_compiler.py +++ b/test/sql/test_compiler.py @@ -59,6 +59,7 @@ from sqlalchemy import Text from sqlalchemy import text from sqlalchemy import TIMESTAMP from sqlalchemy import true +from sqlalchemy import try_cast from sqlalchemy import tuple_ from sqlalchemy import type_coerce from sqlalchemy import types @@ -6044,6 +6045,15 @@ class StringifySpecialTest(fixtures.TestBase): "ALTER TABLE testtbl ADD EXCLUDE USING gist " "(room WITH =)", ) + def test_try_cast(self): + t1 = Table("t1", MetaData(), Column("id", Integer, primary_key=True)) + expr = select(try_cast(t1.c.id, Integer)) + + eq_ignore_whitespace( + str(expr), + "SELECT TRY_CAST(t1.id AS INTEGER) AS id FROM t1", + ) + class KwargPropagationTest(fixtures.TestBase): @classmethod