Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: add JSON type, bindparam support #1147

Open
wants to merge 5 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions sqlalchemy_bigquery/__init__.py
Original file line number Diff line number Diff line change
Expand Up @@ -37,6 +37,7 @@
FLOAT64,
INT64,
INTEGER,
JSON,
NUMERIC,
RECORD,
STRING,
Expand Down Expand Up @@ -74,6 +75,7 @@
"FLOAT64",
"INT64",
"INTEGER",
"JSON",
"NUMERIC",
"RECORD",
"STRING",
Expand Down
8 changes: 8 additions & 0 deletions sqlalchemy_bigquery/_json.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
import sqlalchemy


class JSON(sqlalchemy.sql.sqltypes.JSON):
def bind_expression(self, bindvalue):
# JSON query parameters have type STRING
# This hook ensures that the rendered expression has type JSON
return sqlalchemy.func.PARSE_JSON(bindvalue, type_=self)
Comment on lines +5 to +8
Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

note An alternative here would be to just preserve the STRING type and let BigQuery handle the cast, but this seems hard to reason about. It feels right to have the expression type in BigQuery match the expression type here in SQLAlchemy.

Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Looking at [1] and pondering this - it wouldn't be that surprising if a user wanted to submit invalid JSON as a query parameter at some point. This could be supported by parameterizing this behavior in the type, i.e: JSON(strict=False) or similar. Not worried about it right now, though.

[1] https://cloud.google.com/bigquery/docs/reference/standard-sql/json_functions#non-validation_of_string_inputs

3 changes: 3 additions & 0 deletions sqlalchemy_bigquery/_types.py
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,7 @@
except ImportError: # pragma: NO COVER
pass

from ._json import JSON
from ._struct import STRUCT

_type_map = {
Expand All @@ -41,6 +42,7 @@
"FLOAT": sqlalchemy.types.Float,
"INT64": sqlalchemy.types.Integer,
"INTEGER": sqlalchemy.types.Integer,
"JSON": JSON,
"NUMERIC": sqlalchemy.types.Numeric,
"RECORD": STRUCT,
"STRING": sqlalchemy.types.String,
Expand All @@ -61,6 +63,7 @@
FLOAT = _type_map["FLOAT"]
INT64 = _type_map["INT64"]
INTEGER = _type_map["INTEGER"]
JSON = _type_map["JSON"]
NUMERIC = _type_map["NUMERIC"]
RECORD = _type_map["RECORD"]
STRING = _type_map["STRING"]
Expand Down
18 changes: 17 additions & 1 deletion sqlalchemy_bigquery/base.py
Original file line number Diff line number Diff line change
Expand Up @@ -59,7 +59,7 @@
import re

from .parse_url import parse_url
from . import _helpers, _struct, _types
from . import _helpers, _json, _struct, _types
import sqlalchemy_bigquery_vendored.sqlalchemy.postgresql.base as vendored_postgresql

# Illegal characters is intended to be all characters that are not explicitly
Expand Down Expand Up @@ -641,6 +641,17 @@ def visit_NUMERIC(self, type_, **kw):

visit_DECIMAL = visit_NUMERIC

def visit_JSON(self, type_, **kw):
if isinstance(
kw.get("type_expression"), Column
): # column def
return "JSON"
# FIXME: JSON is not a member of `SqlParameterScalarTypes` in the DBAPI
# For now, we hack around this by:
# - Rewriting the bindparam type to STRING
# - Applying a bind expression that converts the parameter back to JSON
return "STRING"


class BigQueryDDLCompiler(DDLCompiler):
option_datatype_mapping = {
Expand Down Expand Up @@ -1076,6 +1087,7 @@ class BigQueryDialect(DefaultDialect):
sqlalchemy.sql.sqltypes.TIMESTAMP: BQTimestamp,
sqlalchemy.sql.sqltypes.ARRAY: BQArray,
sqlalchemy.sql.sqltypes.Enum: sqlalchemy.sql.sqltypes.Enum,
sqlalchemy.sql.sqltypes.JSON: _json.JSON,
}

def __init__(
Expand All @@ -1086,6 +1098,8 @@ def __init__(
credentials_info=None,
credentials_base64=None,
list_tables_page_size=1000,
json_serializer=None,
json_deserializer=None,
Comment on lines +1101 to +1102
Copy link
Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

note See https://docs.sqlalchemy.org/en/20/core/type_basics.html#sqlalchemy.types.JSON section "Customizing the JSON Serializer"

*args,
**kwargs,
):
Expand All @@ -1098,6 +1112,8 @@ def __init__(
self.identifier_preparer = self.preparer(self)
self.dataset_id = None
self.list_tables_page_size = list_tables_page_size
self._json_serializer = json_serializer
self._json_deserializer = json_deserializer

@classmethod
def dbapi(cls):
Expand Down
64 changes: 64 additions & 0 deletions tests/unit/test__json.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
import json
from unittest import mock

import pytest
import sqlalchemy


@pytest.fixture
def json_table(metadata):
from sqlalchemy_bigquery import JSON

return sqlalchemy.Table("json_table", metadata, sqlalchemy.Column("json", JSON))


@pytest.fixture
def json_data():
return {"foo": "bar"}


def test_set_json_serde(faux_conn, metadata, json_table, json_data):
from sqlalchemy_bigquery import JSON

json_serializer = mock.Mock(side_effect=json.dumps)
json_deserializer = mock.Mock(side_effect=json.loads)

engine = sqlalchemy.create_engine(
"bigquery://myproject/mydataset",
json_serializer=json_serializer,
json_deserializer=json_deserializer,
)

json_column = json_table.c.json

process_bind = json_column.type.bind_processor(engine.dialect)
process_bind(json_data)
assert json_serializer.mock_calls == [mock.call(json_data)]

process_result = json_column.type.result_processor(engine.dialect, JSON)
process_result(json.dumps(json_data))
assert json_deserializer.mock_calls == [mock.call(json.dumps(json_data))]


def test_json_create(faux_conn, metadata, json_table, json_data):
expr = sqlalchemy.schema.CreateTable(json_table)
sql = expr.compile(faux_conn.engine).string
assert sql == "\nCREATE TABLE `json_table` (\n\t`json` JSON\n) \n\n"


def test_json_insert(faux_conn, metadata, json_table, json_data):
expr = sqlalchemy.insert(json_table).values(json=json_data)
sql = expr.compile(faux_conn.engine).string
assert (
sql == "INSERT INTO `json_table` (`json`) VALUES (PARSE_JSON(%(json:STRING)s))"
)


def test_json_where(faux_conn, metadata, json_table, json_data):
expr = sqlalchemy.select(json_table.c.json).where(json_table.c.json == json_data)
sql = expr.compile(faux_conn.engine).string
assert sql == (
"SELECT `json_table`.`json` \n"
"FROM `json_table` \n"
"WHERE `json_table`.`json` = PARSE_JSON(%(json_1:STRING)s)"
)