.. dialect:: sqlite
:name: SQLite
+.. _sqlite_datetime:
Date and Time Types
-------------------
nicely support ordering. There's no reliance on typical "libc" internals for
these functions so historical dates are fully supported.
+Ensuring Text affinity
+^^^^^^^^^^^^^^^^^^^^^^
+
+The DDL rendered for these types is the standard ``DATE``, ``TIME``
+and ``DATETIME`` indicators. However, custom storage formats can also be
+applied to these types. When the
+storage format is detected as containing no alpha characters, the DDL for
+these types is rendered as ``DATE_CHAR``, ``TIME_CHAR``, and ``DATETIME_CHAR``,
+so that the column continues to have textual affinity.
+
+.. seealso::
+
+ `Type Affinity <http://www.sqlite.org/datatype3.html#affinity>`_ - in the SQLite documentation
+
.. _sqlite_autoincrement:
SQLite Auto Incrementing Behavior
from ...engine import default, reflection
from ...sql import compiler
-from ...types import (BLOB, BOOLEAN, CHAR, DATE, DECIMAL, FLOAT,
+from ...types import (BLOB, BOOLEAN, CHAR, DECIMAL, FLOAT,
INTEGER, REAL, NUMERIC, SMALLINT, TEXT,
TIMESTAMP, VARCHAR)
if storage_format is not None:
self._storage_format = storage_format
+ @property
+ def format_is_text_affinity(self):
+ """return True if the storage format will automatically imply
+ a TEXT affinity.
+
+ If the storage format contains no non-numeric characters,
+ it will imply a NUMERIC storage format on SQLite; in this case,
+ the type will generate its DDL as DATE_CHAR, DATETIME_CHAR,
+ TIME_CHAR.
+
+ .. versionadded:: 1.0.0
+
+ """
+ spec = self._storage_format % {
+ "year": 0, "month": 0, "day": 0, "hour": 0,
+ "minute": 0, "second": 0, "microsecond": 0
+ }
+ return bool(re.search(r'[^0-9]', spec))
+
def adapt(self, cls, **kw):
if issubclass(cls, _DateTimeMixin):
if self._storage_format:
'BOOLEAN': sqltypes.BOOLEAN,
'CHAR': sqltypes.CHAR,
'DATE': sqltypes.DATE,
+ 'DATE_CHAR': sqltypes.DATE,
'DATETIME': sqltypes.DATETIME,
+ 'DATETIME_CHAR': sqltypes.DATETIME,
'DOUBLE': sqltypes.FLOAT,
'DECIMAL': sqltypes.DECIMAL,
'FLOAT': sqltypes.FLOAT,
'SMALLINT': sqltypes.SMALLINT,
'TEXT': sqltypes.TEXT,
'TIME': sqltypes.TIME,
+ 'TIME_CHAR': sqltypes.TIME,
'TIMESTAMP': sqltypes.TIMESTAMP,
'VARCHAR': sqltypes.VARCHAR,
'NVARCHAR': sqltypes.NVARCHAR,
def visit_large_binary(self, type_):
return self.visit_BLOB(type_)
+ def visit_DATETIME(self, type_):
+ if not isinstance(type_, _DateTimeMixin) or \
+ type_.format_is_text_affinity:
+ return super(SQLiteTypeCompiler, self).visit_DATETIME(type_)
+ else:
+ return "DATETIME_CHAR"
+
+ def visit_DATE(self, type_):
+ if not isinstance(type_, _DateTimeMixin) or \
+ type_.format_is_text_affinity:
+ return super(SQLiteTypeCompiler, self).visit_DATE(type_)
+ else:
+ return "DATE_CHAR"
+
+ def visit_TIME(self, type_):
+ if not isinstance(type_, _DateTimeMixin) or \
+ type_.format_is_text_affinity:
+ return super(SQLiteTypeCompiler, self).visit_TIME(type_)
+ else:
+ return "TIME_CHAR"
+
class SQLiteIdentifierPreparer(compiler.IdentifierPreparer):
reserved_words = set([
(datetime.datetime(2010, 10, 15, 12, 37),)]
)
+ @testing.provide_metadata
+ def test_custom_datetime_text_affinity(self):
+ sqlite_date = sqlite.DATETIME(
+ storage_format="%(year)04d%(month)02d%(day)02d"
+ "%(hour)02d%(minute)02d%(second)02d",
+ regexp=r"(\d{4})(\d{2})(\d{2})(\d{2})(\d{2})(\d{2})",
+ )
+ t = Table('t', self.metadata, Column('d', sqlite_date))
+ self.metadata.create_all(testing.db)
+ testing.db.execute(
+ t.insert().
+ values(d=datetime.datetime(2010, 10, 15, 12, 37, 0)))
+ testing.db.execute("insert into t (d) values ('20040521000000')")
+ eq_(
+ testing.db.execute("select * from t order by d").fetchall(),
+ [('20040521000000',), ('20101015123700',)]
+ )
+ eq_(
+ testing.db.execute(select([t.c.d]).order_by(t.c.d)).fetchall(),
+ [
+ (datetime.datetime(2004, 5, 21, 0, 0),),
+ (datetime.datetime(2010, 10, 15, 12, 37),)]
+ )
+
+ @testing.provide_metadata
+ def test_custom_date_text_affinity(self):
+ sqlite_date = sqlite.DATE(
+ storage_format="%(year)04d%(month)02d%(day)02d",
+ regexp=r"(\d{4})(\d{2})(\d{2})",
+ )
+ t = Table('t', self.metadata, Column('d', sqlite_date))
+ self.metadata.create_all(testing.db)
+ testing.db.execute(
+ t.insert().
+ values(d=datetime.date(2010, 10, 15)))
+ testing.db.execute("insert into t (d) values ('20040521')")
+ eq_(
+ testing.db.execute("select * from t order by d").fetchall(),
+ [('20040521',), ('20101015',)]
+ )
+ eq_(
+ testing.db.execute(select([t.c.d]).order_by(t.c.d)).fetchall(),
+ [
+ (datetime.date(2004, 5, 21),),
+ (datetime.date(2010, 10, 15),)]
+ )
+
@testing.provide_metadata
def test_custom_date(self):
sqlite_date = sqlite.DATE(
(sqltypes.Time, sqltypes.TIME()),
(sqltypes.BOOLEAN, sqltypes.BOOLEAN()),
(sqltypes.Boolean, sqltypes.BOOLEAN()),
+ (sqlite.DATE(
+ storage_format="%(year)04d%(month)02d%(day)02d",
+ ), sqltypes.DATE()),
+ (sqlite.TIME(
+ storage_format="%(hour)02d%(minute)02d%(second)02d",
+ ), sqltypes.TIME()),
+ (sqlite.DATETIME(
+ storage_format="%(year)04d%(month)02d%(day)02d"
+ "%(hour)02d%(minute)02d%(second)02d",
+ ), sqltypes.DATETIME()),
]
def _unsupported_args_fixture(self):