From: Mike Bayer Date: Wed, 7 Jan 2026 01:03:10 +0000 (-0500) Subject: apply Grouping on left side of JSONB subscript in compiler X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=12ccef924a99b53f1b0a905830df4c2ba03cd7d4;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git apply Grouping on left side of JSONB subscript in compiler Fixed regression in PostgreSQL dialect where JSONB subscription syntax would generate incorrect SQL for :func:`.cast` expressions returning JSONB, causing syntax errors. The dialect now properly wraps cast expressions in parentheses when using the ``[]`` subscription syntax, generating ``(CAST(...))[index]`` instead of ``CAST(...)[index]`` to comply with PostgreSQL syntax requirements. This extends the fix from :ticket:`12778` which addressed the same issue for function calls. This reverts how we did the fix for #12778 in Function.self_group() and instead moves to a direct Grouping() applied in the PG compiler based on isinstance of the left side. in retrospect, when we first did #10927, we **definitely** made the completely wrong choice in how to do this, the original idea to detect when we were in an UPDATE and use [] only then was by **far** what we should have done, given the fact that PG indexes are based on exact syntax matches. but since we've made everyone switch to [] format for their indexes now we can't keep going back and forth. even though PG would like [] to be the defacto syntax it simply is not. We should potentially pursue a dialect/ create_engine option to switch the use of [] back to -> for all cases except UPDATE. Fixes: #13067 Change-Id: I2e0d0f45ebb820d2a8f214550f1d1a500bae223b --- diff --git a/doc/build/changelog/unreleased_20/13067.rst b/doc/build/changelog/unreleased_20/13067.rst new file mode 100644 index 0000000000..12bedfb367 --- /dev/null +++ b/doc/build/changelog/unreleased_20/13067.rst @@ -0,0 +1,11 @@ +.. change:: + :tags: bug, postgresql + :tickets: 13067 + + Fixed regression in PostgreSQL dialect where JSONB subscription syntax + would generate incorrect SQL for :func:`.cast` expressions returning JSONB, + causing syntax errors. The dialect now properly wraps cast expressions in + parentheses when using the ``[]`` subscription syntax, generating + ``(CAST(...))[index]`` instead of ``CAST(...)[index]`` to comply with + PostgreSQL syntax requirements. This extends the fix from :ticket:`12778` + which addressed the same issue for function calls. diff --git a/doc/build/tutorial/data_select.rst b/doc/build/tutorial/data_select.rst index 24e25e0b34..7a976c0873 100644 --- a/doc/build/tutorial/data_select.rst +++ b/doc/build/tutorial/data_select.rst @@ -1476,7 +1476,7 @@ elements:: >>> stmt = select(function_expr["def"]) >>> print(stmt) - {printsql}SELECT (json_object(:json_object_1))[:json_object_2] AS anon_1 + {printsql}SELECT json_object(:json_object_1)[:json_object_2] AS anon_1 Built-in Functions Have Pre-Configured Return Types ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~ diff --git a/lib/sqlalchemy/dialects/postgresql/base.py b/lib/sqlalchemy/dialects/postgresql/base.py index edd726fa38..f990c96112 100644 --- a/lib/sqlalchemy/dialects/postgresql/base.py +++ b/lib/sqlalchemy/dialects/postgresql/base.py @@ -1809,6 +1809,7 @@ from ...sql import coercions from ...sql import compiler from ...sql import elements from ...sql import expression +from ...sql import functions from ...sql import roles from ...sql import sqltypes from ...sql import util as sql_util @@ -2082,10 +2083,14 @@ class PGCompiler(compiler.SQLCompiler): and isinstance(binary.left.type, _json.JSONB) and self.dialect._supports_jsonb_subscripting ): + left = binary.left + if isinstance(left, (functions.FunctionElement, elements.Cast)): + left = elements.Grouping(left) + # for pg14+JSONB use subscript notation: col['key'] instead # of col -> 'key' return "%s[%s]" % ( - self.process(binary.left, **kw), + self.process(left, **kw), self.process(binary.right, **kw), ) else: diff --git a/lib/sqlalchemy/sql/functions.py b/lib/sqlalchemy/sql/functions.py index 11d438bf77..7646ce5a14 100644 --- a/lib/sqlalchemy/sql/functions.py +++ b/lib/sqlalchemy/sql/functions.py @@ -780,7 +780,9 @@ class FunctionElement( # expressions against getitem. This may need to be made # more portable if in the future we support other DBs # besides postgresql. - if against in (operators.getitem, operators.json_getitem_op): + if against is operators.getitem and isinstance( + self.type, sqltypes.ARRAY + ): return Grouping(self) else: return super().self_group(against=against) diff --git a/test/dialect/postgresql/test_compiler.py b/test/dialect/postgresql/test_compiler.py index cb240a74a5..7413af4cfd 100644 --- a/test/dialect/postgresql/test_compiler.py +++ b/test/dialect/postgresql/test_compiler.py @@ -3188,6 +3188,29 @@ class CompileTest(fixtures.TestBase, AssertsCompiledSQL): " AS anon_1 FROM data", ) + def test_jsonb_cast_use_parentheses_with_subscripting(self): + """test #13067 - JSONB cast expressions parenthesized with [] syntax""" + + # Test that JSONB cast expressions are properly parenthesized with [] + # syntax. This ensures correct PostgreSQL syntax: (CAST(...))[index] + # instead of the invalid: CAST(...)[index] + + stmt = select(cast({"foo": "bar"}, JSONB)["foo"]) + self.assert_compile( + stmt, + "SELECT (CAST(%(param_1)s::JSONB AS JSONB))[%(param_2)s::TEXT] " + "AS anon_1", + ) + + # Test with nested cast within subscripts + data = table("data", column("id", Integer), column("x", JSONB)) + stmt = select(data.c.x[cast("key", String)]) + self.assert_compile( + stmt, + "SELECT data.x[CAST(%(param_1)s::VARCHAR AS VARCHAR)] AS anon_1 " + "FROM data", + ) + def test_range_custom_object_hook(self): # See issue #8884 from datetime import date diff --git a/test/dialect/postgresql/test_query.py b/test/dialect/postgresql/test_query.py index 49e9aa9d20..e5d9574a52 100644 --- a/test/dialect/postgresql/test_query.py +++ b/test/dialect/postgresql/test_query.py @@ -1967,7 +1967,7 @@ class TableValuedRoundTripTest(fixtures.TestBase): eq_(connection.execute(stmt).all(), [(1, "foo"), (2, "bar")]) -class JSONUpdateTest(fixtures.TablesTest): +class JSONQueryTest(fixtures.TablesTest): """round trip tests related to using JSON and JSONB in UPDATE statements with PG-specific features @@ -2170,6 +2170,54 @@ class JSONUpdateTest(fixtures.TablesTest): {"tags": ["python", "postgresql", "postgres"], "priority": "high"}, ) + @testing.combinations( + (lambda: cast({"foo": "bar"}, JSONB)["foo"], "bar"), + ( + cast({"user": {"name": "Alice", "age": 30}}, JSONB)["user"][ + "name" + ], + "Alice", + ), + (cast({"x": 1, "y": 2}, JSONB)["x"], 1), + ( + func.jsonb_build_object("key", "value", type_=JSONB)["key"], + "value", + ), + ( + func.jsonb_array_elements( + cast([{"name": "Bob"}, {"name": "Carol"}], JSONB), type_=JSONB + )["name"], + "Bob", + ), + ( + cast(func.jsonb_build_object("key1", "val1", type_=JSONB), JSONB)[ + "key1" + ], + "val1", + ), + ( + func.jsonb_build_array( + cast({"item": "first"}, JSONB), + cast({"item": "second"}, JSONB), + type_=JSONB, + )[0]["item"], + "first", + ), + argnames="expr, expected", + ) + def test_jsonb_cast_and_function_with_subscript( + self, connection, expr, expected + ): + """Test JSONB cast/function expressions with newer subscript [] syntax + that occurs on pg14+ + + these tests cover round trips for #12778 and #13067 (so far) + + """ + stmt = select(expr) + result = connection.scalar(stmt) + eq_(result, expected) + class HstoreUpdateTest(fixtures.TablesTest): """round trip tests related to using HSTORE in UPDATE statements