The package sqlalchemy.types defines the datatype identifiers which may be used when defining metadata. This package includes a set of generic types, a set of SQL-specific subclasses of those types, and a small extension system used by specific database connectors to adapt these generic types into database-specific type objects.
SQLAlchemy comes with a set of standard generic datatypes, which are defined as classes. Types are usually used when defining tables, and can be left as a class or instantiated, for example:
mytable = Table('mytable', metadata, Column('myid', Integer, primary_key=True), Column('data', String(30)), Column('info', Unicode(100)), Column('value', Number(7,4)) )
Following is a rundown of the standard types.
This type is the base type for all string and character types, such as Unicode, TEXT, CLOB, etc. By default it generates a VARCHAR in DDL. It includes an argument length, which indicates the length in characters of the type, as well as convert_unicode and assert_unicode, which are booleans. length will be used as the length argument when generating DDL. If length is omitted, the String type resolves into the TEXT type.
convert_unicode=True indicates that incoming strings, if they are Python unicode strings, will be encoded into a raw bytestring using the encoding attribute of the dialect (defaults to utf-8). Similarly, raw bytestrings coming back from the database will be decoded into unicode objects on the way back.
assert_unicode is set to None by default. When True, it indicates that incoming bind parameters will be checked that they are in fact unicode objects, else an error is raised. A value of 'warn' instead raises a warning. Setting it to None indicates that the dialect-level convert_unicode setting should take place, whereas setting it to False disables it unconditionally (this flag is new as of version 0.4.2).
Both convert_unicode and assert_unicode may be set at the engine level as flags to create_engine().
The Unicode type is shorthand for String with convert_unicode=True and assert_unicode='warn'. When writing a Unicode-aware application, it is strongly recommended that this type is used, and that only Unicode strings are used in the application. By "Unicode string" we mean a string with a u, i.e. u'hello'. Otherwise, particularly when using the ORM, data will be converted to Unicode when it returns from the database, but local data which was generated locally will not be in Unicode format, which can create confusion.
These are the "unbounded" versions of String and Unicode. They have no "length" parameter, and generate a column type of TEXT or CLOB.
Numeric types return decimal.Decimal objects by default. The flag asdecimal=False may be specified which enables the type to pass data straight through. Numeric also takes "precision" and "scale" arguments which are used when CREATE TABLE is issued.
Float types return Python floats. Float also takes a "precision" argument which is used when CREATE TABLE is issued.
back to section topDate and time types return objects from the Python datetime module. Most DBAPIs have built in support for the datetime module, with the noted exception of SQLite. In the case of SQLite, date and time types are stored as strings which are then converted back to datetime objects when rows are returned.
The Interval type deals with datetime.timedelta objects. In Postgres, the native INTERVAL type is used; for others, the value is stored as a date which is relative to the "epoch" (Jan. 1, 1970).
The Binary type generates BLOB or BYTEA when tables are created, and also converts incoming values using the Binary callable provided by each DBAPI.
Boolean typically uses BOOLEAN or SMALLINT on the CREATE TABLE side, and returns Python True or False.
PickleType builds upon the Binary type to apply Python's pickle.dumps() to incoming objects, and pickle.loads() on the way out, allowing any pickleable Python object to be stored as a serialized binary field.
These are subclasses of the generic types and include:
class FLOAT(Numeric) class TEXT(String) class DECIMAL(Numeric) class INT(Integer) INTEGER = INT class TIMESTAMP(DateTime) class DATETIME(DateTime) class CLOB(String) class VARCHAR(String) class CHAR(String) class BLOB(Binary) class BOOLEAN(Boolean)
The idea behind the SQL-specific types is that a CREATE TABLE statement would generate the exact type specified.
Each dialect has its own set of types, many of which are available only within that dialect. For example, MySQL has a BigInteger type and Postgres has an Inet type. To use these, import them from the module explicitly:
from sqlalchemy.databases.mysql import MSEnum, MSBigInteger table = Table('foo', meta, Column('enumerates', MSEnum('a', 'b', 'c')), Column('id', MSBigInteger) )
Or some postgres types:
from sqlalchemy.databases.postgres import PGInet, PGArray table = Table('foo', meta, Column('ipaddress', PGInet), Column('elements', PGArray(str)) # PGArray is available in 0.4, and takes a type argument )
User-defined types can be created which can augment the bind parameter and result processing capabilities of the built in types. This is usually achieved using the TypeDecorator class, which "decorates" the behavior of any existing type. As of version 0.4.2, the new process_bind_param() and process_result_value() methods should be used:
import sqlalchemy.types as types class MyType(types.TypeDecorator): """a type that decorates Unicode, prefixes values with "PREFIX:" on the way in and strips it off on the way out.""" impl = types.Unicode def process_bind_param(self, value, engine): return "PREFIX:" + value def process_result_value(self, value, engine): return value[7:] def copy(self): return MyType(self.impl.length)
Note that the "old" way to process bind parameters and result values, the convert_bind_param() and convert_result_value() methods, are still available. The downside of these is that when using a type which already processes data such as the Unicode type, you need to call the superclass version of these methods directly. Using process_bind_param() and process_result_value(), user-defined code can return and receive the desired Python data directly.
As of version 0.4.2, TypeDecorator should generally be used for any user-defined type which redefines the behavior of another type, including other TypeDecorator subclasses such as PickleType, and the new process_...() methods described above should be used.
To build a type object from scratch, which will not have a corresponding database-specific implementation, subclass TypeEngine:
import sqlalchemy.types as types class MyType(types.TypeEngine): def __init__(self, precision = 8): self.precision = precision def get_col_spec(self): return "MYTYPE(%s)" % self.precision def convert_bind_param(self, value, engine): return value def convert_result_value(self, value, engine): return value
Once you make your type, it's immediately useable:
table = Table('foo', meta, Column('id', Integer, primary_key=True), Column('data', MyType(16)) )