]> git.ipfire.org Git - thirdparty/sqlalchemy/sqlalchemy.git/commitdiff
Fixed JSONB path_match and path_exists operators to use correct type coercion
authorMike Bayer <mike_mp@zzzcomputing.com>
Wed, 31 Dec 2025 20:48:44 +0000 (15:48 -0500)
committerMike Bayer <mike_mp@zzzcomputing.com>
Thu, 1 Jan 2026 16:48:13 +0000 (11:48 -0500)
Fixed issue where PostgreSQL JSONB operators
:meth:`_postgresql.JSONB.Comparator.path_match` and
:meth:`_postgresql.JSONB.Comparator.path_exists` were applying incorrect
``VARCHAR`` casts to the right-hand side operand when used with newer
PostgreSQL drivers such as psycopg. The operators now indicate the
right-hand type as ``JSONPATH``, which currently results in no casting
taking place, but is also compatible with explicit casts if the
implementation were require it at a later point.

Fixes: #13059
Change-Id: I8e1a58361456f7efabf4940339cb5ce2c5a1d5f9
(cherry picked from commit a88f89849e303ab441082de788545ee8a698dc2e)

doc/build/changelog/unreleased_20/13059.rst [new file with mode: 0644]
lib/sqlalchemy/dialects/postgresql/json.py
test/dialect/postgresql/test_types.py

diff --git a/doc/build/changelog/unreleased_20/13059.rst b/doc/build/changelog/unreleased_20/13059.rst
new file mode 100644 (file)
index 0000000..caeca4a
--- /dev/null
@@ -0,0 +1,14 @@
+.. change::
+    :tags: bug, postgresql
+    :tickets: 13059
+
+    Fixed issue where PostgreSQL JSONB operators
+    :meth:`_postgresql.JSONB.Comparator.path_match` and
+    :meth:`_postgresql.JSONB.Comparator.path_exists` were applying incorrect
+    ``VARCHAR`` casts to the right-hand side operand when used with newer
+    PostgreSQL drivers such as psycopg. The operators now indicate the
+    right-hand type as ``JSONPATH``, which currently results in no casting
+    taking place, but is also compatible with explicit casts if the
+    implementation were require it at a later point.
+
+
index fec711e62d4bfabcdc1a3bf2085655c75d2dec88..5baa41df7c73a1bda229ab24939dfe7d5cd22f84 100644 (file)
@@ -33,6 +33,7 @@ from ...sql._typing import _T
 if TYPE_CHECKING:
     from ...engine.interfaces import Dialect
     from ...sql.elements import ColumnElement
+    from ...sql.operators import OperatorType
     from ...sql.type_api import _BindProcessorType
     from ...sql.type_api import _LiteralProcessorType
     from ...sql.type_api import TypeEngine
@@ -311,6 +312,14 @@ class JSONB(JSON):
 
     __visit_name__ = "JSONB"
 
+    def coerce_compared_value(
+        self, op: Optional[OperatorType], value: Any
+    ) -> TypeEngine[Any]:
+        if op in (PATH_MATCH, PATH_EXISTS):
+            return JSON.JSONPathType()
+        else:
+            return super().coerce_compared_value(op, value)
+
     class Comparator(JSON.Comparator[_T]):
         """Define comparison operations for :class:`_types.JSON`."""
 
index acd3b1f2c597f72b1eece3e0fec0b64dd9b1e125..88324196dc6851a808da9048f44c5e8efc6b81fc 100644 (file)
@@ -6561,6 +6561,50 @@ class JSONBRoundTripTest(JSONRoundTripTest):
         res = connection.scalar(q)
         eq_(res, {"k1": {"r6v1": {"subr": [1, 3]}}})
 
+    @testing.only_on("postgresql >= 12")
+    def test_path_exists(self, connection):
+        self._fixture_data(connection)
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_exists("$.k1")
+        )
+        res = connection.scalars(q).all()
+        eq_(set(res), {"r1", "r2", "r3", "r4", "r5", "r6"})
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_exists("$.k3")
+        )
+        res = connection.scalars(q).all()
+        eq_(res, ["r5"])
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_exists("$.k1.r6v1")
+        )
+        res = connection.scalars(q).all()
+        eq_(res, ["r6"])
+
+    @testing.only_on("postgresql >= 12")
+    def test_path_match(self, connection):
+        self._fixture_data(connection)
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_match("$.k3 > 0")
+        )
+        res = connection.scalars(q).all()
+        eq_(res, ["r5"])
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_match("$.k3 == 5")
+        )
+        res = connection.scalars(q).all()
+        eq_(res, ["r5"])
+
+        q = select(self.data_table.c.name).where(
+            self.data_table.c.data.path_match('$.k1 == "r1v1"')
+        )
+        res = connection.scalars(q).all()
+        eq_(res, ["r1"])
+
 
 class JSONBSuiteTest(suite.JSONTest):
     __requires__ = ("postgresql_jsonb",)