From: Yeongbae Jeon Date: Sun, 23 Nov 2025 11:44:43 +0000 (-0500) Subject: Add native BOOLEAN type support for Oracle 23c and later versions X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=6baf3b9fb2e1353101b91ed6968d6aece6d95e0b;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Add native BOOLEAN type support for Oracle 23c and later versions Added support for native BOOLEAN support in Oracle Database 23c and above. The Oracle dialect now renders ``BOOLEAN`` automatically when :class:`.Boolean` is used in DDL, and also now supports direct use of the :class:`.BOOLEAN` datatype, when 23c and above is in use. For Oracle versions prior to 23c, boolean values continue to be emulated using SMALLINT as before. Special case handling is also present to ensure a SMALLINT that's interpreted with the :class:`.Boolean` datatype on Oracle Database 23c and above continues to return bool values. Pull request courtesy Yeongbae Jeon. Co-authored-by: Mike Bayer Fixes: #11633 Closes: #13000 Pull-request: https://github.com/sqlalchemy/sqlalchemy/pull/13000 Pull-request-sha: 65b8a2c92f539c57ab6b0b1bf045bd23eedb1695 Change-Id: I13be32f6bad5d918f6c7c9622f0deae78f5c6551 --- diff --git a/doc/build/changelog/unreleased_21/11633.rst b/doc/build/changelog/unreleased_21/11633.rst new file mode 100644 index 0000000000..fcac955aa9 --- /dev/null +++ b/doc/build/changelog/unreleased_21/11633.rst @@ -0,0 +1,17 @@ +.. change:: + :tags: feature, oracle + :tickets: 11633 + + Added support for native BOOLEAN support in Oracle Database 23c and above. + The Oracle dialect now renders ``BOOLEAN`` automatically when + :class:`.Boolean` is used in DDL, and also now supports direct use of the + :class:`.BOOLEAN` datatype, when 23c and above is in use. For Oracle + versions prior to 23c, boolean values continue to be emulated using + SMALLINT as before. Special case handling is also present to ensure a + SMALLINT that's interpreted with the :class:`.Boolean` datatype on Oracle + Database 23c and above continues to return bool values. Pull request + courtesy Yeongbae Jeon. + + .. seealso:: + + :ref:`oracle_boolean_support` diff --git a/doc/build/dialects/oracle.rst b/doc/build/dialects/oracle.rst index fc19a81fa4..8601b81158 100644 --- a/doc/build/dialects/oracle.rst +++ b/doc/build/dialects/oracle.rst @@ -15,6 +15,7 @@ originate from :mod:`sqlalchemy.types` or from the local dialect:: from sqlalchemy.dialects.oracle import ( BFILE, BLOB, + BOOLEAN, CHAR, CLOB, DATE, @@ -48,6 +49,9 @@ construction arguments, are as follows: .. autoclass:: BINARY_FLOAT :members: __init__ +.. autoclass:: BOOLEAN + :members: __init__ + .. autoclass:: DATE :members: __init__ diff --git a/lib/sqlalchemy/dialects/oracle/__init__.py b/lib/sqlalchemy/dialects/oracle/__init__.py index 566edf1c3b..12c06a84e7 100644 --- a/lib/sqlalchemy/dialects/oracle/__init__.py +++ b/lib/sqlalchemy/dialects/oracle/__init__.py @@ -14,6 +14,7 @@ from .base import BFILE from .base import BINARY_DOUBLE from .base import BINARY_FLOAT from .base import BLOB +from .base import BOOLEAN from .base import CHAR from .base import CLOB from .base import DATE @@ -71,6 +72,7 @@ __all__ = ( "NVARCHAR2", "ROWID", "REAL", + "BOOLEAN", "VECTOR", "VectorDistanceType", "VectorIndexType", diff --git a/lib/sqlalchemy/dialects/oracle/base.py b/lib/sqlalchemy/dialects/oracle/base.py index 390afdd8f5..bbcde831a1 100644 --- a/lib/sqlalchemy/dialects/oracle/base.py +++ b/lib/sqlalchemy/dialects/oracle/base.py @@ -640,6 +640,49 @@ E.g. to use this datatype in a :class:`.Table` definition:: ), ) +.. _oracle_boolean_support: + +Boolean Support +--------------- + +.. versionadded:: 2.1 + +Oracle Database 23ai introduced native support for the ``BOOLEAN`` datatype. +The Oracle dialect automatically detects the database version and uses the +native ``BOOLEAN`` type when available, or falls back to emulation using +``SMALLINT`` on older Oracle versions. + +The standard :class:`_types.Boolean` type can be used in table definitions:: + + from sqlalchemy import Boolean, Column, Integer, Table, MetaData + + metadata = MetaData() + + my_table = Table( + "my_table", + metadata, + Column("id", Integer, primary_key=True), + Column("flag", Boolean), + ) + +On Oracle 23ai and later, this will generate DDL using the native ``BOOLEAN`` type: + +.. code-block:: sql + + CREATE TABLE my_table ( + id INTEGER NOT NULL, + flag BOOLEAN, + PRIMARY KEY (id) + ) + +On earlier Oracle versions, it will use ``SMALLINT`` for storage with appropriate +constraints and conversions. + +The :class:`_types.Boolean` type is also available as ``BOOLEAN`` from the Oracle +dialect for consistency with other type names:: + + from sqlalchemy.dialects.oracle import BOOLEAN + DateTime Compatibility ---------------------- @@ -964,6 +1007,7 @@ from .types import _OracleDate from .types import BFILE from .types import BINARY_DOUBLE from .types import BINARY_FLOAT +from .types import BOOLEAN from .types import DATE from .types import FLOAT from .types import INTERVAL @@ -1060,6 +1104,7 @@ ischema_names = { "BINARY_DOUBLE": BINARY_DOUBLE, "BINARY_FLOAT": BINARY_FLOAT, "ROWID": ROWID, + "BOOLEAN": BOOLEAN, "VECTOR": VECTOR, } @@ -1207,7 +1252,10 @@ class OracleTypeCompiler(compiler.GenericTypeCompiler): return self.visit_NUMBER(type_, precision=19, **kw) def visit_boolean(self, type_, **kw): - return self.visit_SMALLINT(type_, **kw) + if self.dialect.supports_native_boolean: + return self.visit_BOOLEAN(type_, **kw) + else: + return self.visit_SMALLINT(type_, **kw) def visit_RAW(self, type_, **kw): if type_.length: @@ -1958,6 +2006,7 @@ class OracleDialect(default.DefaultDialect): cte_follows_insert = True returns_native_bytes = True + supports_native_boolean = True supports_sequences = True sequences_optional = False postfetch_lastrowid = False @@ -2053,6 +2102,7 @@ class OracleDialect(default.DefaultDialect): self.colspecs.pop(sqltypes.Interval) self.use_ansi = False + self.supports_native_boolean = self.server_version_info >= (23,) self.supports_identity_columns = self.server_version_info >= (12,) self._supports_offset_fetch = ( self.enable_offset_fetch and self.server_version_info >= (12,) diff --git a/lib/sqlalchemy/dialects/oracle/cx_oracle.py b/lib/sqlalchemy/dialects/oracle/cx_oracle.py index 1ef02fb5c4..ea17ccf6a8 100644 --- a/lib/sqlalchemy/dialects/oracle/cx_oracle.py +++ b/lib/sqlalchemy/dialects/oracle/cx_oracle.py @@ -485,6 +485,7 @@ from ...engine import interfaces from ...engine import processors from ...sql import sqltypes from ...sql._typing import is_sql_compiler +from ...sql.sqltypes import Boolean # source: # https://github.com/oracle/python-cx_Oracle/issues/596#issuecomment-999243649 @@ -881,7 +882,17 @@ class OracleExecutionContext_cx_oracle(OracleExecutionContext): decimal.Decimal, arraysize=len_params, ) - + elif isinstance(type_impl, Boolean): + if self.dialect.supports_native_boolean: + out_parameters[name] = self.cursor.var( + cx_Oracle.BOOLEAN, arraysize=len_params + ) + else: + out_parameters[name] = self.cursor.var( + cx_Oracle.NUMBER, + arraysize=len_params, + outconverter=bool, + ) else: out_parameters[name] = self.cursor.var( dbtype, arraysize=len_params diff --git a/lib/sqlalchemy/dialects/oracle/types.py b/lib/sqlalchemy/dialects/oracle/types.py index 4ad624475c..a1cd6f756e 100644 --- a/lib/sqlalchemy/dialects/oracle/types.py +++ b/lib/sqlalchemy/dialects/oracle/types.py @@ -23,6 +23,9 @@ if TYPE_CHECKING: from ...sql.type_api import _LiteralProcessorType +BOOLEAN = sqltypes.BOOLEAN + + class RAW(sqltypes._Binary): __visit_name__ = "RAW" @@ -314,5 +317,34 @@ class ROWID(sqltypes.TypeEngine): class _OracleBoolean(sqltypes.Boolean): + def get_dbapi_type(self, dbapi): + # this can probably be dbapi.BOOLEAN (including for older verisons), + # however sticking with NUMBER to avoid any surprises with older + # versions or non-bool values return dbapi.NUMBER + + def result_processor(self, dialect, coltype): + # we dont need a result processor even if we are not native + # boolean because we use an outputtypehandler + return None + + def _cx_oracle_outputtypehandler(self, dialect): + cx_Oracle = dialect.dbapi + + def handler(cursor, name, default_type, size, precision, scale): + # if native boolean no handler needed + if default_type is cx_Oracle.BOOLEAN: + return None + + # OTOH if we are getting a number back and we are either + # native boolean pulling from a smallint, or non native + # boolean pulling from a smallint that's emulated, use bool + return cursor.var( + cx_Oracle.NUMBER, + 255, + arraysize=cursor.arraysize, + outconverter=bool, + ) + + return handler diff --git a/test/dialect/oracle/test_dialect.py b/test/dialect/oracle/test_dialect.py index 05f7fa6497..2b6bd5f5bf 100644 --- a/test/dialect/oracle/test_dialect.py +++ b/test/dialect/oracle/test_dialect.py @@ -740,6 +740,19 @@ class CompatFlagsTest(fixtures.TestBase, AssertsCompiledSQL): self.assert_compile(Unicode(50), "NVARCHAR2(50)", dialect=dialect) self.assert_compile(UnicodeText(), "NCLOB", dialect=dialect) + def test_native_boolean_flag(self): + dialect = self._dialect((19, 0, 0)) + + # starts as true + assert dialect.supports_native_boolean + + dialect.initialize(Mock()) + assert not dialect.supports_native_boolean + + dialect = self._dialect((23, 0, 0)) + dialect.initialize(Mock()) + assert dialect.supports_native_boolean + def test_ident_length_in_13_is_30(self): from sqlalchemy import __version__ diff --git a/test/dialect/oracle/test_reflection.py b/test/dialect/oracle/test_reflection.py index 0dd61da03a..3f363dafee 100644 --- a/test/dialect/oracle/test_reflection.py +++ b/test/dialect/oracle/test_reflection.py @@ -722,6 +722,21 @@ class TableReflectionTest(fixtures.TestBase): tb1 = Table("test_vector", m2, autoload_with=connection) assert tb1.columns.keys() == ["id", "name", "embedding"] + @testing.only_on("oracle>=23") + def test_reflection_w_boolean_column(self, connection, metadata): + tb1 = Table( + "test_boolean", + metadata, + Column("id", Integer, primary_key=True), + Column("flag", oracle.BOOLEAN), + ) + metadata.create_all(connection) + + m2 = MetaData() + + tb1 = Table("test_boolean", m2, autoload_with=connection) + assert isinstance(tb1.c.flag.type, oracle.BOOLEAN) + class ViewReflectionTest(fixtures.TestBase): __only_on__ = "oracle" diff --git a/test/dialect/oracle/test_types.py b/test/dialect/oracle/test_types.py index 890bcf7751..4b28422a0b 100644 --- a/test/dialect/oracle/test_types.py +++ b/test/dialect/oracle/test_types.py @@ -24,6 +24,7 @@ from sqlalchemy import MetaData from sqlalchemy import NCHAR from sqlalchemy import Numeric from sqlalchemy import NVARCHAR +from sqlalchemy import schema from sqlalchemy import select from sqlalchemy import SmallInteger from sqlalchemy import String @@ -248,6 +249,46 @@ class DialectTypesTest(fixtures.TestBase, AssertsCompiledSQL): def test_interval_literal_processor(self, type_, expected): self.assert_compile(type_, expected, literal_binds=True) + def test_compile_boolean_native(self): + dialect = oracle.OracleDialect() + dialect.supports_native_boolean = True + + t = Table( + "t", + MetaData(), + Column("x", sqltypes.Boolean), + Column("y", oracle.BOOLEAN), + Column( + "z", sqltypes.Boolean().with_variant(oracle.BOOLEAN, "oracle") + ), + ) + + self.assert_compile( + schema.CreateTable(t), + "CREATE TABLE t (x BOOLEAN, y BOOLEAN, z BOOLEAN)", + dialect=dialect, + ) + + def test_compile_boolean_emulated(self): + dialect = oracle.OracleDialect() + dialect.supports_native_boolean = False + + t = Table( + "t", + MetaData(), + Column("x", sqltypes.Boolean), + Column("y", oracle.BOOLEAN), + Column( + "z", sqltypes.Boolean().with_variant(oracle.BOOLEAN, "oracle") + ), + ) + + self.assert_compile( + schema.CreateTable(t), + "CREATE TABLE t (x SMALLINT, y BOOLEAN, z BOOLEAN)", + dialect=dialect, + ) + class TypesTest(fixtures.TestBase): __only_on__ = "oracle" @@ -1196,6 +1237,177 @@ class TypesTest(fixtures.TestBase): eq_(result[1].indices, array.array("I", [1, 2])) eq_(result[1].values, array.array("f", [23.25, 221.625])) + @testing.only_on("oracle>=23.0") + def test_boolean_native(self, metadata, connection): + """Test native BOOLEAN type on Oracle 23c+""" + t = Table( + "boolean_test", + metadata, + Column("id", Integer, primary_key=True), + Column("x", sqltypes.Boolean), + Column("y", oracle.BOOLEAN), + Column( + "z", sqltypes.Boolean().with_variant(oracle.BOOLEAN, "oracle") + ), + ) + t.create(connection) + + # Insert test data + connection.execute( + t.insert(), + [ + dict(id=1, x=True, y=True, z=True), + dict(id=2, x=False, y=False, z=False), + dict(id=3, x=None, y=None, z=None), + ], + ) + + # Test SELECT + rows = connection.execute(t.select().order_by(t.c.id)).fetchall() + + for row, expected in zip( + rows, + [ + (1, True, True, True), + (2, False, False, False), + (3, None, None, None), + ], + ): + for rval, expval in zip(row, expected): + # use is_() to ensure boolean type + is_(rval, expval) + + # Test WHERE clause with boolean + result = connection.execute(t.select().where(t.c.x == True)).fetchall() + eq_(len(result), 1) + eq_(result[0][0], 1) + + result = connection.execute( + t.select().where(t.c.x == False) + ).fetchall() + eq_(len(result), 1) + eq_(result[0][0], 2) + + def test_boolean_emulated(self, metadata, testing_engine): + """Test emulated BOOLEAN type behavior + + This test forces emulated mode by setting + supports_native_boolean=False, even on Oracle 23c+. This verifies + that the emulation layer still works correctly when native BOOLEAN + is available but not used. + + Note: We only test sqltypes.Boolean here, not oracle.BOOLEAN or + with_variant(), because those explicitly request native BOOLEAN type + regardless of the supports_native_boolean setting. + """ + + e = testing_engine() + + with e.connect() as connection: + e.dialect.supports_native_boolean = False + + t = Table( + "boolean_emulated_test", + metadata, + Column("id", Integer, primary_key=True), + Column("data", sqltypes.Boolean), + ) + t.create(connection) + + # Insert test data + connection.execute( + t.insert(), + [ + dict(id=1, data=True), + dict(id=2, data=False), + dict(id=3, data=None), + ], + ) + + # Test SELECT - emulated boolean returns True/False + rows = connection.execute(t.select().order_by(t.c.id)).fetchall() + + for row, expected in zip( + rows, + [ + (1, True, True, True), + (2, False, False, False), + (3, None, None, None), + ], + ): + for rval, expval in zip(row, expected): + # use is_() to ensure boolean type + is_(rval, expval) + + # Test WHERE clause with boolean + result = connection.execute( + t.select().where(t.c.data == True) + ).fetchall() + eq_(len(result), 1) + eq_(result[0][0], 1) + + result = connection.execute( + t.select().where(t.c.data == False) + ).fetchall() + eq_(len(result), 1) + eq_(result[0][0], 2) + + @testing.only_on("oracle>=23.0") + def test_boolean_upgrade(self, metadata, connection): + """test that a table that has SMALLINT from a prior SQLAlchemy + version or older oracle version still works when native boolean is + flipped on for it. + + """ + t = Table( + "boolean_test", + metadata, + Column("id", Integer, primary_key=True), + Column("x", sqltypes.SMALLINT), + ) + t.create(connection) + + # Insert test data + connection.execute( + t.insert(), + [ + dict(id=1, x=1), + dict(id=2, x=0), + ], + ) + + # now let's say we upgraded to oracle 23c and have the new + # SQLAlchemy + + tt = Table( + "boolean_test", + MetaData(), + Column("id", Integer, primary_key=True), + Column("x", sqltypes.Boolean), + ) + + returning_result = connection.execute( + tt.insert().returning(tt.c.id, tt.c.x), + [ + dict(id=3, x=True), + dict(id=4, x=False), + ], + ) + rr = returning_result.all() + + for row, expected in zip(rr, [(3, True), (4, False)]): + for rval, expval in zip(row, expected): + # use is_() to ensure boolean type + is_(rval, expval) + + rows = connection.execute(tt.select().order_by(tt.c.id)).fetchall() + for row, expected in zip( + rows, [(1, True), (2, False), (3, True), (4, False)] + ): + for rval, expval in zip(row, expected): + # use is_() to ensure boolean type + is_(rval, expval) + class LOBFetchTest(fixtures.TablesTest): __only_on__ = "oracle"