]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
Add native BOOLEAN type support for Oracle 23c+
authorYeongbae Jeon <ybjeon01@naver.com>
Sat, 22 Nov 2025 06:30:39 +0000 (15:30 +0900)
committerYeongbae Jeon <ybjeon01@naver.com>
Sun, 23 Nov 2025 11:14:57 +0000 (20:14 +0900)
Oracle Database 23c introduced native BOOLEAN type support.
This change adds automatic detection and usage of native BOOLEAN
when connected to Oracle 23c or later. For earlier versions,
boolean values continue to be emulated using SMALLINT.

Fixes: #11633
doc/build/changelog/unreleased_21/11633.rst [new file with mode: 0644]
doc/build/dialects/oracle.rst
lib/sqlalchemy/dialects/oracle/__init__.py
lib/sqlalchemy/dialects/oracle/base.py
lib/sqlalchemy/dialects/oracle/types.py
test/dialect/oracle/test_dialect.py
test/dialect/oracle/test_reflection.py
test/dialect/oracle/test_types.py

diff --git a/doc/build/changelog/unreleased_21/11633.rst b/doc/build/changelog/unreleased_21/11633.rst
new file mode 100644 (file)
index 0000000..feefac4
--- /dev/null
@@ -0,0 +1,9 @@
+.. change::
+    :tags: feature, oracle
+    :tickets: 11633
+
+    Added support for native BOOLEAN type in Oracle Database 23c and above.
+    The Oracle dialect now automatically uses the native BOOLEAN type when
+    connected to Oracle Database 23c or later, as determined by the server
+    version. For Oracle versions prior to 23c, boolean values continue to be
+    emulated using SMALLINT as before.
index fc19a81fa4b8ade1541f006315fe8e0631a6410a..8601b811580b242a44568be76d6509ec49d2e6df 100644 (file)
@@ -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__
 
index 566edf1c3b66085af208e47706b62847e0414da9..12c06a84e72d0dfbbd931896ac1b4e76a4caac42 100644 (file)
@@ -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",
index 390afdd8f5844a158b97f3976ba56700b84296bc..90291e7e0d0b3663f9c5f58c93b6c83c90a02683 100644 (file)
@@ -640,6 +640,47 @@ E.g. to use this datatype in a :class:`.Table` definition::
         ),
     )
 
+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 +1005,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 +1102,7 @@ ischema_names = {
     "BINARY_DOUBLE": BINARY_DOUBLE,
     "BINARY_FLOAT": BINARY_FLOAT,
     "ROWID": ROWID,
+    "BOOLEAN": BOOLEAN,
     "VECTOR": VECTOR,
 }
 
@@ -1207,7 +1250,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:
@@ -2053,6 +2099,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,)
index 4ad624475ce6e8f14e770ec0ebdcb4b7e29cd8e6..c41cbe9393aa4cea6754f9524fa19fb11af718b1 100644 (file)
@@ -23,6 +23,9 @@ if TYPE_CHECKING:
     from ...sql.type_api import _LiteralProcessorType
 
 
+BOOLEAN = sqltypes.BOOLEAN
+
+
 class RAW(sqltypes._Binary):
     __visit_name__ = "RAW"
 
index 05f7fa64975fdd90b3b273bc18d10241f13ac393..75e485cb3dd0d3dccdd79f22d302412629d8b57c 100644 (file)
@@ -740,6 +740,15 @@ 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))
+        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__
 
index 93f89cf5d56c8a606270751c4dab816806148dc3..6e68d1c4d6aa63c88b9dea248c4f8c5e960aff7d 100644 (file)
@@ -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"
index c905b921b90247ee4c03b08f33ae9de734a92816..d64c8f47520f106050cfd4486a75aff560419734 100644 (file)
@@ -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"
@@ -1193,6 +1234,109 @@ 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()
+
+        eq_(rows[0], (1, True, True, True))
+        eq_(rows[1], (2, False, False, False))
+        eq_(rows[2], (3, None, None, None))
+
+        # 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, connection):
+        """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.
+        """
+        # Temporarily force emulated boolean mode
+        original_supports_native = connection.dialect.supports_native_boolean
+        connection.dialect.supports_native_boolean = False
+
+        try:
+            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()
+
+            eq_(rows[0], (1, True))
+            eq_(rows[1], (2, False))
+            eq_(rows[2], (3, None))
+
+            # 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)
+        finally:
+            # Restore original setting
+            connection.dialect.supports_native_boolean = (
+                original_supports_native
+            )
+
 
 class LOBFetchTest(fixtures.TablesTest):
     __only_on__ = "oracle"