From: Ilja Everilä Date: Thu, 15 Mar 2018 14:18:13 +0000 (-0400) Subject: Sqlite json X-Git-Tag: rel_1_3_0b1~134 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=62d59088dfe86d7ecabd85ad626ee108b668acc5;p=thirdparty%2Fsqlalchemy%2Fsqlalchemy.git Sqlite json Added support for SQLite's json functionality via the new SQLite implementation for :class:`.sqltypes.JSON`, :class:`.sqlite.JSON`. The name used for the type is ``JSON``, following an example found at SQLite's own documentation. Pull request courtesy Ilja Everilä. Fixes: #3850 Change-Id: I3d2714fb8655343a99d13dc751b16b93d05d7dda Pull-request: https://github.com/zzzeek/sqlalchemy/pull/434 --- diff --git a/doc/build/changelog/migration_13.rst b/doc/build/changelog/migration_13.rst index 980d12619a..86187a2f4e 100644 --- a/doc/build/changelog/migration_13.rst +++ b/doc/build/changelog/migration_13.rst @@ -174,6 +174,27 @@ This is a much more lightweight ping than the previous method of emitting Dialect Improvements and Changes - SQLite ============================================= +.. _change_3850: + +Support for SQLite JSON Added +----------------------------- + +A new datatype :class:`.sqlite.JSON` is added which implements SQLite's json +member access functions on behalf of the :class:`.types.JSON` +base datatype. The SQLite ``JSON_EXTRACT`` and ``JSON_QUOTE`` functions +are used by the implementation to provide basic JSON support. + +Note that the name of the datatype itself as rendered in the database is +the name "JSON". This will create a SQLite datatype with "numeric" affinity, +which normally should not be an issue except in the case of a JSON value that +consists of single integer value. Nevertheless, following an example +in SQLite's own documentation at https://www.sqlite.org/json1.html the name +JSON is being used for its familiarity. + + +:ticket:`3850` + + Dialect Improvements and Changes - Oracle ============================================= diff --git a/doc/build/changelog/unreleased_13/3850.rst b/doc/build/changelog/unreleased_13/3850.rst new file mode 100644 index 0000000000..138414d5cf --- /dev/null +++ b/doc/build/changelog/unreleased_13/3850.rst @@ -0,0 +1,12 @@ +.. change:: + :tags: feature, sqlite + :tickets: 3850 + + Added support for SQLite's json functionality via the new + SQLite implementation for :class:`.types.JSON`, :class:`.sqlite.JSON`. + The name used for the type is ``JSON``, following an example found at + SQLite's own documentation. Pull request courtesy Ilja Everilä. + + .. seealso:: + + :ref:`change_3850` diff --git a/doc/build/dialects/sqlite.rst b/doc/build/dialects/sqlite.rst index 936ae253f1..85a4bab4c9 100644 --- a/doc/build/dialects/sqlite.rst +++ b/doc/build/dialects/sqlite.rst @@ -14,7 +14,7 @@ they originate from :mod:`sqlalchemy.types` or from the local dialect:: from sqlalchemy.dialects.sqlite import \ BLOB, BOOLEAN, CHAR, DATE, DATETIME, DECIMAL, FLOAT, \ - INTEGER, NUMERIC, SMALLINT, TEXT, TIME, TIMESTAMP, \ + INTEGER, NUMERIC, JSON, SMALLINT, TEXT, TIME, TIMESTAMP, \ VARCHAR .. module:: sqlalchemy.dialects.sqlite @@ -23,6 +23,8 @@ they originate from :mod:`sqlalchemy.types` or from the local dialect:: .. autoclass:: DATE +.. autoclass:: JSON + .. autoclass:: TIME Pysqlite diff --git a/lib/sqlalchemy/dialects/sqlite/__init__.py b/lib/sqlalchemy/dialects/sqlite/__init__.py index cb5337adb9..a735815213 100644 --- a/lib/sqlalchemy/dialects/sqlite/__init__.py +++ b/lib/sqlalchemy/dialects/sqlite/__init__.py @@ -8,7 +8,7 @@ from . import base, pysqlite, pysqlcipher # noqa from sqlalchemy.dialects.sqlite.base import ( - BLOB, BOOLEAN, CHAR, DATE, DATETIME, DECIMAL, FLOAT, INTEGER, REAL, + BLOB, BOOLEAN, CHAR, DATE, DATETIME, DECIMAL, FLOAT, INTEGER, JSON, REAL, NUMERIC, SMALLINT, TEXT, TIME, TIMESTAMP, VARCHAR ) @@ -17,5 +17,5 @@ base.dialect = dialect = pysqlite.dialect __all__ = ('BLOB', 'BOOLEAN', 'CHAR', 'DATE', 'DATETIME', 'DECIMAL', - 'FLOAT', 'INTEGER', 'NUMERIC', 'SMALLINT', 'TEXT', 'TIME', + 'FLOAT', 'INTEGER', 'JSON', 'NUMERIC', 'SMALLINT', 'TEXT', 'TIME', 'TIMESTAMP', 'VARCHAR', 'REAL', 'dialect') diff --git a/lib/sqlalchemy/dialects/sqlite/base.py b/lib/sqlalchemy/dialects/sqlite/base.py index 5117025fb0..c6932be8f3 100644 --- a/lib/sqlalchemy/dialects/sqlite/base.py +++ b/lib/sqlalchemy/dialects/sqlite/base.py @@ -478,6 +478,7 @@ from ...sql import compiler from ...types import (BLOB, BOOLEAN, CHAR, DECIMAL, FLOAT, INTEGER, REAL, NUMERIC, SMALLINT, TEXT, TIMESTAMP, VARCHAR) +from .json import JSON, JSONIndexType, JSONPathType class _DateTimeMixin(object): @@ -753,6 +754,9 @@ class TIME(_DateTimeMixin, sqltypes.Time): colspecs = { sqltypes.Date: DATE, sqltypes.DateTime: DATETIME, + sqltypes.JSON: JSON, + sqltypes.JSON.JSONIndexType: JSONIndexType, + sqltypes.JSON.JSONPathType: JSONPathType, sqltypes.Time: TIME, } @@ -771,6 +775,7 @@ ischema_names = { 'FLOAT': sqltypes.FLOAT, 'INT': sqltypes.INTEGER, 'INTEGER': sqltypes.INTEGER, + 'JSON': JSON, 'NUMERIC': sqltypes.NUMERIC, 'REAL': sqltypes.REAL, 'SMALLINT': sqltypes.SMALLINT, @@ -855,6 +860,16 @@ class SQLiteCompiler(compiler.SQLCompiler): return "%s IS %s" % (self.process(binary.left), self.process(binary.right)) + def visit_json_getitem_op_binary(self, binary, operator, **kw): + return "JSON_QUOTE(JSON_EXTRACT(%s, %s))" % ( + self.process(binary.left, **kw), + self.process(binary.right, **kw)) + + def visit_json_path_getitem_op_binary(self, binary, operator, **kw): + return "JSON_QUOTE(JSON_EXTRACT(%s, %s))" % ( + self.process(binary.left, **kw), + self.process(binary.right, **kw)) + class SQLiteDDLCompiler(compiler.DDLCompiler): @@ -973,6 +988,12 @@ class SQLiteTypeCompiler(compiler.GenericTypeCompiler): else: return "TIME_CHAR" + def visit_JSON(self, type_, **kw): + # note this name provides NUMERIC affinity, not TEXT. + # should not be an issue unless the JSON value consists of a single + # numeric value. JSONTEXT can be used if this case is required. + return "JSON" + class SQLiteIdentifierPreparer(compiler.IdentifierPreparer): reserved_words = set([ @@ -1065,9 +1086,12 @@ class SQLiteDialect(default.DefaultDialect): _broken_fk_pragma_quotes = False _broken_dotted_colnames = False - def __init__(self, isolation_level=None, native_datetime=False, **kwargs): + def __init__(self, isolation_level=None, native_datetime=False, + _json_serializer=None, _json_deserializer=None, **kwargs): default.DefaultDialect.__init__(self, **kwargs) self.isolation_level = isolation_level + self._json_serializer = _json_serializer + self._json_deserializer = _json_deserializer # this flag used by pysqlite dialect, and perhaps others in the # future, to indicate the driver is handling date/timestamp diff --git a/lib/sqlalchemy/dialects/sqlite/json.py b/lib/sqlalchemy/dialects/sqlite/json.py new file mode 100644 index 0000000000..90929fbd89 --- /dev/null +++ b/lib/sqlalchemy/dialects/sqlite/json.py @@ -0,0 +1,77 @@ +from ... import types as sqltypes + + +class JSON(sqltypes.JSON): + """SQLite JSON type. + + SQLite supports JSON as of version 3.9 through its JSON1_ extension. Note + that JSON1_ is a + `loadable extension `_ and as such + may not be available, or may require run-time loading. + + The :class:`.sqlite.JSON` type supports persistence of JSON values + as well as the core index operations provided by :class:`.types.JSON` + datatype, by adapting the operations to render the ``JSON_EXTRACT`` + function wrapped in the ``JSON_QUOTE`` function at the database level. + Extracted values are quoted in order to ensure that the results are + always JSON string values. + + .. versionadded:: 1.3 + + .. seealso:: + + JSON1_ + + .. _JSON1: https://www.sqlite.org/json1.html + + """ + + +# Note: these objects currently match exactly those of MySQL, however since +# these are not generalizable to all JSON implementations, remain separately +# implemented for each dialect. +class _FormatTypeMixin(object): + def _format_value(self, value): + raise NotImplementedError() + + def bind_processor(self, dialect): + super_proc = self.string_bind_processor(dialect) + + def process(value): + value = self._format_value(value) + if super_proc: + value = super_proc(value) + return value + + return process + + def literal_processor(self, dialect): + super_proc = self.string_literal_processor(dialect) + + def process(value): + value = self._format_value(value) + if super_proc: + value = super_proc(value) + return value + + return process + + +class JSONIndexType(_FormatTypeMixin, sqltypes.JSON.JSONIndexType): + + def _format_value(self, value): + if isinstance(value, int): + value = "$[%s]" % value + else: + value = '$."%s"' % value + return value + + +class JSONPathType(_FormatTypeMixin, sqltypes.JSON.JSONPathType): + def _format_value(self, value): + return "$%s" % ( + "".join([ + "[%s]" % elem if isinstance(elem, int) + else '."%s"' % elem for elem in value + ]) + ) diff --git a/lib/sqlalchemy/sql/sqltypes.py b/lib/sqlalchemy/sql/sqltypes.py index a2ae9de502..08af78606a 100644 --- a/lib/sqlalchemy/sql/sqltypes.py +++ b/lib/sqlalchemy/sql/sqltypes.py @@ -1834,8 +1834,13 @@ class JSON(Indexable, TypeEngine): .. note:: :class:`.types.JSON` is provided as a facade for vendor-specific JSON types. Since it supports JSON SQL operations, it only - works on backends that have an actual JSON type, currently - PostgreSQL as well as certain versions of MySQL. + works on backends that have an actual JSON type, currently: + + * PostgreSQL + + * MySQL as of version 5.7 (MariaDB as of the 10.2 series does not) + + * SQLite as of version 3.9 :class:`.types.JSON` is part of the Core in support of the growing popularity of native JSON datatypes. diff --git a/test/dialect/test_sqlite.py b/test/dialect/test_sqlite.py index d2d563208e..5e2535b30c 100644 --- a/test/dialect/test_sqlite.py +++ b/test/dialect/test_sqlite.py @@ -219,6 +219,68 @@ class TestTypes(fixtures.TestBase, AssertsExecutionResults): isinstance(bindproc(util.u('some string')), util.text_type) +class JSONTest(fixtures.TestBase): + + __requires__ = ('json_type', ) + __only_on__ = 'sqlite' + + @testing.provide_metadata + @testing.requires.reflects_json_type + def test_reflection(self): + Table( + 'json_test', self.metadata, + Column('foo', sqlite.JSON) + ) + self.metadata.create_all() + + reflected = Table('json_test', MetaData(), autoload_with=testing.db) + is_(reflected.c.foo.type._type_affinity, sqltypes.JSON) + assert isinstance(reflected.c.foo.type, sqlite.JSON) + + @testing.provide_metadata + def test_rudimentary_roundtrip(self): + sqlite_json = Table( + 'json_test', self.metadata, + Column('foo', sqlite.JSON) + ) + + self.metadata.create_all() + + value = { + 'json': {'foo': 'bar'}, + 'recs': ['one', 'two'] + } + + with testing.db.connect() as conn: + conn.execute(sqlite_json.insert(), foo=value) + + eq_( + conn.scalar(select([sqlite_json.c.foo])), + value + ) + + @testing.provide_metadata + def test_extract_subobject(self): + sqlite_json = Table( + 'json_test', self.metadata, + Column('foo', sqlite.JSON) + ) + + self.metadata.create_all() + + value = { + 'json': {'foo': 'bar'}, + } + + with testing.db.connect() as conn: + conn.execute(sqlite_json.insert(), foo=value) + + eq_( + conn.scalar(select([sqlite_json.c.foo['json']])), + value['json'] + ) + + class DateTimeTest(fixtures.TestBase, AssertsCompiledSQL): def test_time_microseconds(self): diff --git a/test/requirements.py b/test/requirements.py index 57324a3f40..b11a6317fd 100644 --- a/test/requirements.py +++ b/test/requirements.py @@ -729,7 +729,8 @@ class DefaultRequirements(SuiteRequirements): (10, 2, 7) ) ), - "postgresql >= 9.3" + "postgresql >= 9.3", + "sqlite >= 3.9" ]) @property @@ -737,7 +738,8 @@ class DefaultRequirements(SuiteRequirements): return only_on([ lambda config: against(config, "mysql >= 5.7") and not config.db.dialect._is_mariadb, - "postgresql >= 9.3" + "postgresql >= 9.3", + "sqlite >= 3.9" ]) @property