4.1. SQLite (mis)features

As the SQLite package is constantly being improved, you should refer to the original documentation about the SQL features it supports and about the SQL features it doesn't support.

One noticeable difference between SQLite and other SQL database engines is that the former is typeless. All data are stored as strings, and you can insert any type of data into any column. While the SQLite author has good reasons for this feature, it is an obstacle to using the strongly typed retrieval functions of libdbi. The only way out is to declare the column types in a CREATE TABLE statement just as you would with any other SQL database engine. As an example, the following statement is perfectly fine with SQLite, but not with the sqlite driver:

CREATE TABLE foo (a,b,c)

However, the following statement is fine with SQLite, the sqlite driver, and just about any other SQL database server:

CREATE TABLE foo (a INTEGER,b TEXT,c VARCHAR(64))

The following table lists the column types which are positively recognized by the sqlite driver. Essentially all column types supported by MySQL and PostgreSQL are supported by this driver as well, making it reasonably easy to write portable SQL code. All other column types are treated as strings.

Table 4-1. SQL column types supported by the sqlite driver

typedescription
TINYBLOB, BLOB, MEDIUMBLOB, LONGBLOB, BYTEAString types of unlimited length. Binary data must be safely encoded, see text.
CHAR(), VARCHAR(), TINYTEXT, TEXT, MEDIUMTEXT, LONGTEXTString types of unlimited length. There is no chopping or padding performed by the database engine.
ENUMString type of unlimited length. In contrast to MySQL, choosing ENUM over VARCHAR does not save any storage space.
SETString type of unlimited length. In contrast to MySQL, the input is not checked against the list of allowed values.
YEARString type of unlimited length. MySQL stores 2 or 4 digit years as a 1 byte value, whereas the SQLite drivers stores the string as provided.
TINYINT, INT1, CHARA 1 byte type used to store one character, a signed integer between -128 and 127, or an unsigned integer between 0 and 255.
SMALLINT, INT22 byte (short) integer type used to store a signed integer between -32768 and 32767 or an unsigned integer between 0 and 65535.
MEDIUMINT3 byte integer type used to store a signed integer between -8388608 and 8388607 or an unsigned integer between 0 and 16777215.
INT, INTEGER, INT44 byte (long) integer type used to store a signed integer between -2147483648 and 2147483647 or an unsigned integer between 0 and 4294967295.
BIGINT, INT88 byte (long long) integer type used to store a signed integer between -9223372036854775808 and 9223372036854775807 or an unsigned integer between 0 and 18446744073709551615.
DECIMAL, NUMERICA string type of unlimited length used to store floating-point numbers of arbitrary precision.
TIMESTAMP, DATETIMEA string type of unlimited length used to store date/time combinations. The required format is 'YYYY-MM-DD HH:MM:SS', anything following this pattern is ignored.
DATEA string type of unlimited length used to store a date. The required format is 'YYYY-MM-DD', anything following this pattern is ignored.
TIMEA string type of unlimited length used to store a time. The required format is 'HH:MM:SS', anything following this pattern is ignored.
FLOAT, FLOAT4, REALA 4 byte floating-point number. The range is -3.402823466E+38 to -1.175494351E-38, 0, and 1.175494351E-38 to 3.402823466E+38. Please note that MySQL treats REAL as an 8 byte instead of a 4 byte float like PostgreSQL.
DOUBLE, DOUBLE PRECISION, FLOAT8An 8 byte floating-point number. The range is -1.7976931348623157E+308 to -2.2250738585072014E-308, 0, and 2.2250738585072014E-308 to 1.7976931348623157E+308.

Another difference is the lack of access control on the database engine level. Most SQL database servers implement some mechanisms to restrict who is allowed to fiddle with the databases and who is not. As SQLite uses regular files to store its databases, all available access control is on the filesystem level. There is no SQL interface to this kind of access control, but chmod and chown are your friends.

SQLite appears to implement row and column counters as C long int values. This limits the maximum number of rows somewhat compared to other SQL database engines.

SQLite does not have specific support for binary data. If you want to store binary data (e.g. character sequences containing NULL bytes) in a fashion that is portable across all database servers supported by libdbi, use the libdbi function _dbd_encode_binary.

SQLite currently supports different character encodings only as compile-time options. There is no way to change the encoding at runtime or per database.