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
=============================================
--- /dev/null
+.. 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`
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
.. autoclass:: DATE
+.. autoclass:: JSON
+
.. autoclass:: TIME
Pysqlite
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
)
__all__ = ('BLOB', 'BOOLEAN', 'CHAR', 'DATE', 'DATETIME', 'DECIMAL',
- 'FLOAT', 'INTEGER', 'NUMERIC', 'SMALLINT', 'TEXT', 'TIME',
+ 'FLOAT', 'INTEGER', 'JSON', 'NUMERIC', 'SMALLINT', 'TEXT', 'TIME',
'TIMESTAMP', 'VARCHAR', 'REAL', 'dialect')
from ...types import (BLOB, BOOLEAN, CHAR, DECIMAL, FLOAT,
INTEGER, REAL, NUMERIC, SMALLINT, TEXT,
TIMESTAMP, VARCHAR)
+from .json import JSON, JSONIndexType, JSONPathType
class _DateTimeMixin(object):
colspecs = {
sqltypes.Date: DATE,
sqltypes.DateTime: DATETIME,
+ sqltypes.JSON: JSON,
+ sqltypes.JSON.JSONIndexType: JSONIndexType,
+ sqltypes.JSON.JSONPathType: JSONPathType,
sqltypes.Time: TIME,
}
'FLOAT': sqltypes.FLOAT,
'INT': sqltypes.INTEGER,
'INTEGER': sqltypes.INTEGER,
+ 'JSON': JSON,
'NUMERIC': sqltypes.NUMERIC,
'REAL': sqltypes.REAL,
'SMALLINT': sqltypes.SMALLINT,
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):
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([
_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
--- /dev/null
+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 <https://www.sqlite.org/loadext.html>`_ 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
+ ])
+ )
.. 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.
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):
(10, 2, 7)
)
),
- "postgresql >= 9.3"
+ "postgresql >= 9.3",
+ "sqlite >= 3.9"
])
@property
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