.. _Cython: https://cython.org/
+.. _change_4926:
+
+Python division operator performs true division for all backends; added floor division
+---------------------------------------------------------------------------------------
+
+The Core expression language now supports both "true division" (i.e. the ``/``
+Python operator) and "floor division" (i.e. the ``//`` Python operator)
+including backend-specific behaviors to normalize different databases in this
+regard.
+
+Given a "true division" operation against two integer values::
+
+ expr = literal(5, Integer) / literal(10, Integer)
+
+The SQL division operator on PostgreSQL for example normally acts as "floor division"
+when used against integers, meaning the above result would return the integer
+"0". For this and similar backends, SQLAlchemy now renders the SQL using
+a form which is equivalent towards::
+
+ %(param_1)s / CAST(%(param_2)s AS NUMERIC)
+
+With param_1=5, param_2=10, so that the return expression will be of type
+NUMERIC, typically as the Python value ``decimal.Decimal("0.5")``.
+
+Given a "floor division" operation against two integer values::
+
+ expr = literal(5, Integer) // literal(10, Integer)
+
+The SQL division operator on MySQL and Oracle for example normally acts
+as "true division" when used against integers, meaning the above result
+would return the floating point value "0.5". For these and similar backends,
+SQLAlchemy now renders the SQL using a form which is equivalent towards::
+
+ FLOOR(%(param_1)s / %(param_2)s)
+
+With param_1=5, param_2=10, so that the return expression will be of type
+INTEGER, as the Python value ``0``.
+
+The backwards-incompatible change here would be if an application using
+PostgreSQL, SQL Server, or SQLite which relied on the Python "truediv" operator
+to return an integer value in all cases. Applications which rely upon this
+behavior should instead use the Python "floor division" operator ``//``
+for these operations, or for forwards compatibility when using a previous
+SQLAlchemy version, the floor function::
+
+ expr = func.floor(literal(5, Integer) / literal(10, Integer))
+
+The above form would be needed on any SQLAlchemy version prior to 2.0
+in order to provide backend-agnostic floor division.
+
+:ticket:`4926`
+
+
+
.. _migration_20_overview:
1.x -> 2.x Migration Overview
--- /dev/null
+.. change::
+ :tags: bug, sql
+ :tickets: 4926
+
+ Implemented full support for "truediv" and "floordiv" using the
+ "/" and "//" operators. A "truediv" operation between two expressions
+ using :class:`_types.Integer` now considers the result to be
+ :class:`_types.Numeric`, and the dialect-level compilation will cast
+ the right operand to a numeric type on a dialect-specific basis to ensure
+ truediv is achieved. For floordiv, conversion is also added for those
+ databases that don't already do floordiv by default (MySQL, Oracle) and
+ the ``FLOOR()`` function is rendered in this case, as well as for
+ cases where the right operand is not an integer (needed for PostgreSQL,
+ others).
+
+ The change resolves issues both with inconsistent behavior of the
+ division operator on different backends and also fixes an issue where
+ integer division on Oracle would fail to be able to fetch a result due
+ to inappropriate outputtypehandlers.
+
+ .. seealso::
+
+ :ref:`change_4926`
\ No newline at end of file
>>> from sqlalchemy import column, select
>>> from sqlalchemy import create_engine
>>> engine = create_engine("sqlite+pysqlite:///:memory:", echo=True, future=True)
- >>> from sqlalchemy import MetaData, Table, Column, Integer, String
+ >>> from sqlalchemy import MetaData, Table, Column, Integer, String, Numeric
>>> metadata_obj = MetaData()
>>> user_table = Table(
... "user_account",
..
-* :meth:`_sql.ColumnOperators.__div__`, :meth:`_sql.ColumnOperators.__rdiv__` (Python "``/``" operator)::
+* :meth:`_sql.ColumnOperators.__truediv__`, :meth:`_sql.ColumnOperators.__rtruediv__` (Python "``/``" operator).
+ This is the Python ``truediv`` operator, which will ensure integer true division occurs::
>>> print(column('x') / 5)
- x / :x_1
+ x / CAST(:x_1 AS NUMERIC)
>>> print(5 / column('x'))
+ :x_1 / CAST(x AS NUMERIC)
+
+ .. versionchanged:: 2.0 The Python ``/`` operator now ensures integer true division takes place
+
+ ..
+
+* :meth:`_sql.ColumnOperators.__floordiv__`, :meth:`_sql.ColumnOperators.__rfloordiv__` (Python "``//``" operator).
+ This is the Python ``floordiv`` operator, which will ensure floor division occurs.
+ For the default backend as well as backends such as PostgreSQL, the SQL ``/`` operator normally
+ behaves this way for integer values::
+
+ >>> print(column('x') // 5)
+ x / :x_1
+ >>> print(5 // column('x', Integer))
:x_1 / x
+ For backends that don't use floor division by default, or when used with numeric values,
+ the FLOOR() function is used to ensure floor division::
+
+ >>> print(column('x') // 5.5)
+ FLOOR(x / :x_1)
+ >>> print(5 // column('x', Numeric))
+ FLOOR(:x_1 / x)
+
+ .. versionadded:: 2.0 Support for FLOOR division
+
..
max_index_name_length = 64
max_constraint_name_length = 64
+ div_is_floordiv = False
+
supports_native_enum = True
supports_sequences = False # default for MySQL ...
implicit_returning = True
+ div_is_floordiv = False
+
supports_simple_order_by_label = False
cte_follows_insert = True
},
)
+ def visit_truediv_binary(self, binary, operator, **kw):
+ return (
+ self.process(binary.left, **kw)
+ + " / "
+ + "(%s + 0.0)" % self.process(binary.right, **kw)
+ )
+
def visit_now_func(self, fn, **kw):
return "CURRENT_TIMESTAMP"
""" # noqa
+import math
import os
import re
return None
return re.search(a, b) is not None
+ create_func_kw = {"deterministic": True} if util.py38 else {}
+
def set_regexp(dbapi_connection):
dbapi_connection.create_function(
- "regexp",
- 2,
- regexp,
+ "regexp", 2, regexp, **create_func_kw
+ )
+
+ def floor_func(dbapi_connection):
+ # NOTE: floor is optionally present in sqlite 3.35+ , however
+ # as it is normally non-present we deliver floor() unconditionally
+ # for now.
+ # https://www.sqlite.org/lang_mathfunc.html
+ dbapi_connection.create_function(
+ "floor", 1, math.floor, **create_func_kw
)
- fns = [set_regexp]
+ fns = [set_regexp, floor_func]
def connect(conn):
for fn in fns:
inline_comments = False
supports_statement_cache = True
+ div_is_floordiv = True
+
bind_typing = interfaces.BindTyping.NONE
include_set_input_sizes = None
operators.mul: " * ",
operators.sub: " - ",
operators.mod: " % ",
- operators.truediv: " / ",
operators.neg: "-",
operators.lt: " < ",
operators.le: " <= ",
"Unary expression has no operator or modifier"
)
+ def visit_truediv_binary(self, binary, operator, **kw):
+ if self.dialect.div_is_floordiv:
+ return (
+ self.process(binary.left, **kw)
+ + " / "
+ # TODO: would need a fast cast again here,
+ # unless we want to use an implicit cast like "+ 0.0"
+ + self.process(
+ elements.Cast(binary.right, sqltypes.Numeric()), **kw
+ )
+ )
+ else:
+ return (
+ self.process(binary.left, **kw)
+ + " / "
+ + self.process(binary.right, **kw)
+ )
+
+ def visit_floordiv_binary(self, binary, operator, **kw):
+ if (
+ self.dialect.div_is_floordiv
+ and binary.right.type._type_affinity is sqltypes.Integer
+ ):
+ return (
+ self.process(binary.left, **kw)
+ + " / "
+ + self.process(binary.right, **kw)
+ )
+ else:
+ return "FLOOR(%s)" % (
+ self.process(binary.left, **kw)
+ + " / "
+ + self.process(binary.right, **kw)
+ )
+
def visit_is_true_unary_operator(self, element, operator, **kw):
if (
element._is_implicitly_boolean
"div": (_binary_operate,),
"mod": (_binary_operate,),
"truediv": (_binary_operate,),
+ "floordiv": (_binary_operate,),
"custom_op": (_custom_op_operate,),
"json_path_getitem_op": (_binary_operate,),
"json_getitem_op": (_binary_operate,),
from operator import and_
from operator import contains
from operator import eq
+from operator import floordiv
from operator import ge
from operator import getitem
from operator import gt
def __truediv__(self, other):
"""Implement the ``/`` operator.
- In a column context, produces the clause ``a / b``.
+ In a column context, produces the clause ``a / b``, and
+ considers the result type to be numeric.
+
+ .. versionchanged:: 2.0 The truediv operator against two integers
+ is now considered to return a numeric value. Behavior on specific
+ backends may vary.
"""
return self.operate(truediv, other)
"""
return self.reverse_operate(truediv, other)
+ def __floordiv__(self, other):
+ """Implement the ``//`` operator.
+
+ In a column context, produces the clause ``a / b``,
+ which is the same as "truediv", but considers the result
+ type to be integer.
+
+ .. versionadded:: 2.0
+
+ """
+ return self.operate(floordiv, other)
+
+ def __rfloordiv__(self, other):
+ """Implement the ``//`` operator in reverse.
+
+ See :meth:`.ColumnOperators.__floordiv__`.
+
+ """
+ return self.reverse_operate(floordiv, other)
+
_commutative = {eq, ne, add, mul}
_comparison = {eq, ne, lt, gt, ge, le}
json_path_getitem_op: 15,
mul: 8,
truediv: 8,
+ floordiv: 8,
mod: 8,
neg: 8,
add: 7,
@util.memoized_property
def _expression_adaptations(self):
- # TODO: need a dictionary object that will
- # handle operators generically here, this is incomplete
return {
operators.add: {
Date: Date,
Integer: self.__class__,
Numeric: Numeric,
},
- operators.truediv: {Integer: self.__class__, Numeric: Numeric},
+ operators.truediv: {Integer: Numeric, Numeric: Numeric},
+ operators.floordiv: {Integer: self.__class__, Numeric: Numeric},
operators.sub: {Integer: self.__class__, Numeric: Numeric},
}
from ... import Integer
from ... import JSON
from ... import literal
+from ... import literal_column
from ... import MetaData
from ... import null
from ... import Numeric
eq_(result, {2})
+class TrueDivTest(fixtures.TestBase):
+ @testing.combinations(
+ ("15", "10", 1.5),
+ ("-15", "10", -1.5),
+ argnames="left, right, expected",
+ )
+ def test_truediv_integer(self, connection, left, right, expected):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(
+ select(
+ literal_column(left, type_=Integer())
+ / literal_column(right, type_=Integer())
+ )
+ ),
+ expected,
+ )
+
+ @testing.combinations(
+ ("15", "10", 1), ("-15", "5", -3), argnames="left, right, expected"
+ )
+ def test_floordiv_integer(self, connection, left, right, expected):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(
+ select(
+ literal_column(left, type_=Integer())
+ // literal_column(right, type_=Integer())
+ )
+ ),
+ expected,
+ )
+
+ @testing.combinations(
+ ("5.52", "2.4", "2.3"), argnames="left, right, expected"
+ )
+ def test_truediv_numeric(self, connection, left, right, expected):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(
+ select(
+ literal_column(left, type_=Numeric())
+ / literal_column(right, type_=Numeric())
+ )
+ ),
+ decimal.Decimal(expected),
+ )
+
+ @testing.combinations(
+ ("5.52", "2.4", "2.0"), argnames="left, right, expected"
+ )
+ def test_floordiv_numeric(self, connection, left, right, expected):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(
+ select(
+ literal_column(left, type_=Numeric())
+ // literal_column(right, type_=Numeric())
+ )
+ ),
+ decimal.Decimal(expected),
+ )
+
+ def test_truediv_integer_bound(self, connection):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(select(literal(15) / literal(10))),
+ 1.5,
+ )
+
+ def test_floordiv_integer_bound(self, connection):
+ """test #4926"""
+
+ eq_(
+ connection.scalar(select(literal(15) // literal(10))),
+ 1,
+ )
+
+
class NumericTest(_LiteralRoundTripFixture, fixtures.TestBase):
__backend__ = True
"TimeMicrosecondsTest",
"TimestampMicrosecondsTest",
"TimeTest",
+ "TrueDivTest",
"DateTimeMicrosecondsTest",
"DateHistoricTest",
"StringTest",
from sqlalchemy import Float
from sqlalchemy import Integer
from sqlalchemy import LargeBinary
+from sqlalchemy import literal
from sqlalchemy import MetaData
from sqlalchemy import NCHAR
from sqlalchemy import Numeric
assert x == 5
assert isinstance(x, int)
+ def test_integer_truediv(self, connection):
+ """test #4926"""
+
+ stmt = select(literal(1, Integer) / literal(2, Integer))
+ eq_(connection.scalar(stmt), decimal.Decimal("0.5"))
+
def test_rowid(self, metadata, connection):
t = Table("t1", metadata, Column("x", Integer))
m = MetaData()
tbl = Table("testtbl", m, Column("x", Integer), Column("y", Integer))
- idx1 = Index("test_idx1", 5 / (tbl.c.x + tbl.c.y))
+ idx1 = Index("test_idx1", 5 // (tbl.c.x + tbl.c.y))
self.assert_compile(
schema.CreateIndex(idx1),
"CREATE INDEX test_idx1 ON testtbl ((5 / (x + y)))",
(operators.add, "+"),
(operators.mul, "*"),
(operators.sub, "-"),
- (operators.truediv, "/"),
argnames="py_op, sql_op",
id_="ar",
)
(value_tbl.c.val2 - value_tbl.c.val1) / value_tbl.c.val1,
),
"SELECT values.id, (values.val2 - values.val1) "
- "/ values.val1 AS anon_1 FROM values",
+ "/ CAST(values.val1 AS NUMERIC) AS anon_1 FROM values",
)
self.assert_compile(
(value_tbl.c.val2 - value_tbl.c.val1) / value_tbl.c.val1 > 2.0,
),
"SELECT values.id FROM values WHERE "
- "(values.val2 - values.val1) / values.val1 > :param_1",
+ "(values.val2 - values.val1) / "
+ "CAST(values.val1 AS NUMERIC) > :param_1",
)
self.assert_compile(
> 2.0,
),
"SELECT values.id FROM values WHERE "
- "(values.val1 / (values.val2 - values.val1)) "
- "/ values.val1 > :param_1",
+ "(values.val1 / CAST((values.val2 - values.val1) AS NUMERIC)) "
+ "/ CAST(values.val1 AS NUMERIC) > :param_1",
)
def test_percent_chars(self):
.where(
regional_sales.c.total_sales
> select(
- func.sum(regional_sales.c.total_sales) / 10
+ func.sum(regional_sales.c.total_sales) // 10
).scalar_subquery()
)
.cte("top_regions")
def test_associativity_7(self):
f = column("f")
# because - less precedent than /
- self.assert_compile(f / (f - f), "f / (f - f)")
+ self.assert_compile(f / (f - f), "f / CAST((f - f) AS NUMERIC)")
def test_associativity_8(self):
f = column("f")
- self.assert_compile(f / (f - f).label("foo"), "f / (f - f)")
+ self.assert_compile(
+ f / (f - f).label("foo"), "f / CAST((f - f) AS NUMERIC)"
+ )
def test_associativity_9(self):
f = column("f")
- self.assert_compile(f / f - f, "f / f - f")
+ self.assert_compile(f / f - f, "f / CAST(f AS NUMERIC) - f")
def test_associativity_10(self):
f = column("f")
- self.assert_compile((f / f) - f, "f / f - f")
+ self.assert_compile((f / f) - f, "f / CAST(f AS NUMERIC) - f")
def test_associativity_11(self):
f = column("f")
- self.assert_compile((f / f).label("foo") - f, "f / f - f")
+ self.assert_compile(
+ (f / f).label("foo") - f, "f / CAST(f AS NUMERIC) - f"
+ )
def test_associativity_12(self):
f = column("f")
# because / more precedent than -
- self.assert_compile(f - (f / f), "f - f / f")
+ self.assert_compile(f - (f / f), "f - f / CAST(f AS NUMERIC)")
def test_associativity_13(self):
f = column("f")
- self.assert_compile(f - (f / f).label("foo"), "f - f / f")
+ self.assert_compile(
+ f - (f / f).label("foo"), "f - f / CAST(f AS NUMERIC)"
+ )
def test_associativity_14(self):
f = column("f")
- self.assert_compile(f - f / f, "f - f / f")
+ self.assert_compile(f - f / f, "f - f / CAST(f AS NUMERIC)")
def test_associativity_15(self):
f = column("f")
- self.assert_compile((f - f) / f, "(f - f) / f")
+ self.assert_compile((f - f) / f, "(f - f) / CAST(f AS NUMERIC)")
def test_associativity_16(self):
f = column("f")
- self.assert_compile(((f - f) / f) - f, "(f - f) / f - f")
+ self.assert_compile(
+ ((f - f) / f) - f, "(f - f) / CAST(f AS NUMERIC) - f"
+ )
def test_associativity_17(self):
f = column("f")
# - lower precedence than /
- self.assert_compile((f - f) / (f - f), "(f - f) / (f - f)")
+ self.assert_compile(
+ (f - f) / (f - f), "(f - f) / CAST((f - f) AS NUMERIC)"
+ )
def test_associativity_18(self):
f = column("f")
# / higher precedence than -
- self.assert_compile((f / f) - (f / f), "f / f - f / f")
+ self.assert_compile(
+ (f / f) - (f / f),
+ "f / CAST(f AS NUMERIC) - f / CAST(f AS NUMERIC)",
+ )
def test_associativity_19(self):
f = column("f")
- self.assert_compile((f / f) - (f - f), "f / f - (f - f)")
+ self.assert_compile(
+ (f / f) - (f - f), "f / CAST(f AS NUMERIC) - (f - f)"
+ )
def test_associativity_20(self):
f = column("f")
- self.assert_compile((f / f) / (f - f), "(f / f) / (f - f)")
+ self.assert_compile(
+ (f / f) / (f - f),
+ "(f / CAST(f AS NUMERIC)) / CAST((f - f) AS NUMERIC)",
+ )
def test_associativity_21(self):
f = column("f")
- self.assert_compile(f / (f / (f - f)), "f / (f / (f - f))")
+ self.assert_compile(
+ f / (f / (f - f)),
+ "f / CAST((f / CAST((f - f) AS NUMERIC)) AS NUMERIC)",
+ )
def test_associativity_22(self):
f = column("f")
("add", operator.add, "+"),
("mul", operator.mul, "*"),
("sub", operator.sub, "-"),
- ("div", operator.truediv, "/"),
("mod", operator.mod, "%"),
id_="iaa",
)
):
self.assert_compile(py_op(lhs, rhs), res % sql_op)
+ def test_truediv_op_integer(self):
+ self.assert_compile(
+ 5 / literal(5), ":param_1 / CAST(:param_2 AS NUMERIC)"
+ )
+
+ def test_floordiv_op_integer(self):
+ self.assert_compile(5 // literal(5), ":param_1 / :param_2")
+
+ def test_floordiv_op_numeric(self):
+ self.assert_compile(5.10 // literal(5.5), "FLOOR(:param_1 / :param_2)")
+
@testing.combinations(
("format", "mytable.myid %% %s"),
("qmark", "mytable.myid % ?"),
dialect=default.DefaultDialect(paramstyle=paramstyle),
)
+ @testing.combinations(
+ (operator.add,),
+ (operator.mul,),
+ (operator.sub,),
+ (operator.floordiv),
+ )
+ def test_integer_integer_coercion_to_integer(self, op):
+ expr = op(column("bar", Integer()), column("foo", Integer()))
+ assert isinstance(expr.type, Integer)
+
+ @testing.combinations(
+ (operator.add,),
+ (operator.mul,),
+ (operator.sub,),
+ (operator.truediv,),
+ )
+ def test_integer_numeric_coercion_to_numeric(self, op):
+ expr = op(column("bar", Integer()), column("foo", Numeric(10, 2)))
+ assert isinstance(expr.type, Numeric)
+ expr = op(column("foo", Numeric(10, 2)), column("bar", Integer()))
+ assert isinstance(expr.type, Numeric)
+
+ def test_integer_truediv(self):
+ expr = column("bar", Integer()) / column("foo", Integer)
+ assert isinstance(expr.type, Numeric)
+
+ def test_integer_floordiv(self):
+ expr = column("bar", Integer()) // column("foo", Integer)
+ assert isinstance(expr.type, Integer)
+
class ComparisonOperatorTest(fixtures.TestBase, testing.AssertsCompiledSQL):
__dialect__ = "default"
assert isinstance(subq2.c.foo.type, MyType)
def test_type_coerce_selfgroup(self):
- no_group = column("a") / type_coerce(column("x"), Integer)
- group = column("b") / type_coerce(column("y") * column("w"), Integer)
+ no_group = column("a") // type_coerce(column("x"), Integer)
+ group = column("b") // type_coerce(column("y") * column("w"), Integer)
self.assert_compile(no_group, "a / x")
self.assert_compile(group, "b / (y * w)")