A BLOB
is a binary large object that can hold
a variable amount of data. The four BLOB
types are TINYBLOB
, BLOB
,
MEDIUMBLOB
, and LONGBLOB
.
These differ only in the maximum length of the values they can
hold. The four TEXT
types are
TINYTEXT
, TEXT
,
MEDIUMTEXT
, and LONGTEXT
.
These correspond to the four BLOB
types and
have the same maximum lengths and storage requirements. See
Section 11.6, “Data Type Storage Requirements”.
BLOB
values are treated as binary strings
(byte strings). They have no character set, and sorting and
comparison are based on the numeric values of the bytes in
column values. TEXT
values are treated as
nonbinary strings (character strings). They have a character
set, and values are sorted and compared based on the collation
of the character set.
If strict SQL mode is not enabled and you assign a value to a
BLOB
or TEXT
column that
exceeds the column's maximum length, the value is truncated to
fit and a warning is generated. For truncation of nonspace
characters, you can cause an error to occur (rather than a
warning) and suppress insertion of the value by using strict SQL
mode. See Section 5.1.7, “Server SQL Modes”.
Beginning with MySQL 5.1.24, truncation of excess trailing
spaces from values to be inserted into
TEXT
columns always generates a
warning, regardless of the SQL mode.
For TEXT
and BLOB
columns,
there is no padding on insert and no bytes are stripped on
select.
If a TEXT
column is indexed, index entry
comparisons are space-padded at the end. This means that, if the
index requires unique values, duplicate-key errors will occur
for values that differ only in the number of trailing spaces.
For example, if a table contains 'a'
, an
attempt to store 'a '
causes a
duplicate-key error. This is not true for
BLOB
columns.
In most respects, you can regard a BLOB
column as a VARBINARY
column that
can be as large as you like. Similarly, you can regard a
TEXT
column as a
VARCHAR
column.
BLOB
and TEXT
differ from
VARBINARY
and
VARCHAR
in the following ways:
For indexes on BLOB
and
TEXT
columns, you must specify an index
prefix length. For CHAR
and
VARCHAR
, a prefix length is
optional. See Section 8.5.1, “Column Indexes”.
If you use the BINARY
attribute with a
TEXT
data type, the column is assigned the
binary collation of the column character set.
LONG
and LONG VARCHAR
map
to the MEDIUMTEXT
data type. This is a
compatibility feature.
MySQL Connector/ODBC defines BLOB
values as
LONGVARBINARY
and TEXT
values as LONGVARCHAR
.
Because BLOB
and TEXT
values can be extremely long, you might encounter some
constraints in using them:
Only the first
max_sort_length
bytes of
the column are used when sorting. The default value of
max_sort_length
is 1024.
You can make more bytes significant in sorting or grouping
by increasing the value of
max_sort_length
at server
startup or runtime. Any client can change the value of its
session max_sort_length
variable:
mysql>SET max_sort_length = 2000;
mysql>SELECT id, comment FROM t
->ORDER BY comment;
Instances of BLOB
or
TEXT
columns in the result of a query
that is processed using a temporary table causes the server
to use a table on disk rather than in memory because the
MEMORY
storage engine does not support
those data types (see
Section 8.8.5, “How MySQL Uses Internal Temporary Tables”). Use of disk
incurs a performance penalty, so include
BLOB
or TEXT
columns
in the query result only if they are really needed. For
example, avoid using
SELECT *
,
which selects all columns.
The maximum size of a BLOB
or
TEXT
object is determined by its type,
but the largest value you actually can transmit between the
client and server is determined by the amount of available
memory and the size of the communications buffers. You can
change the message buffer size by changing the value of the
max_allowed_packet
variable, but you must do so for both the server and your
client program. For example, both mysql
and mysqldump enable you to change the
client-side
max_allowed_packet
value.
See Section 8.9.2, “Tuning Server Parameters”,
Section 4.5.1, “mysql — The MySQL Command-Line Tool”, and Section 4.5.4, “mysqldump — A Database Backup Program”.
You may also want to compare the packet sizes and the size
of the data objects you are storing with the storage
requirements, see Section 11.6, “Data Type Storage Requirements”
Each BLOB
or TEXT
value is
represented internally by a separately allocated object. This is
in contrast to all other data types, for which storage is
allocated once per column when the table is opened.
In some cases, it may be desirable to store binary data such as
media files in BLOB
or
TEXT
columns. You may find MySQL's string
handling functions useful for working with such data. See
Section 12.5, “String Functions”. For security and other
reasons, it is usually preferable to do so using application
code rather than giving application users the
FILE
privilege. You can discuss
specifics for various languages and platforms in the MySQL
Forums (http://forums.mysql.com/).
User Comments
A pratical example of how write and read images into MySQL tables,
using Trolltech Qt4/C++
This example is for who reads/record images in tables
using fields BLOB.
First: Create a table, for example:
CREATE TABLE picture (
ID INTEGER AUTO_INCREMENT,
IMAGE BLOB,
PRIMARY KEY (ID)
) ENGINE=InnoDB;
2) To read a image to a QByteArray
QString fileName = "IMAGE.JPG";
QImage image(filaName);
LBL_IMAGE->setPixmap(QPixmap::fromImage(image)); // Put image into QLabel object (optional)
// load image to bytearray
QByteArray ba;
QFile f(fileName);
if(f.open(QIODevice::ReadOnly))
{
ba = f.readAll();
f.close();
}
// Writing the image into table
QSqlDatabase::database().transaction();
QSqlQuery query;
query.prepare( "INSERT INTO picture ( IMAGE ) VALUES (:IMAGE)" );
query.bindValue(":IMAGE", ba);
query.exec();
if( query.lastError().isValid()) {
qDebug() << query.lastError().text();
QSqlDatabase::database().rollback();
} else
QSqlDatabase::database().commit();
3) Now, recovery the field with the image
int idx = 1; // The records ID to recover
QSqlDatabase::database().transaction();
QSqlQuery query;
query.prepare("SELECT ID, IMAGE FROM picture WHERE ID=:ID");
query.bindValue(":ID", idx);
query.exec();
query.next();
if( query.lastError().isValid()) {
qDebug() << query.lastError().text();
QSqlDatabase::database().rollback();
} else {
QByteArray ba1 = query.value(1).toByteArray();
QPixmap pic;
pic.loadFromData( ba1);
// Show the image into a QLabel object
LBL_IMAGE->setPixmap(pic);
QSqlDatabase::database().commit();
}
This example works fine and I use it frequently.
Thanks.
On MS Windows the "no DEFAULT" rule is an error, while on other platforms it is often a warning. While not a bug, it's possible to get trapped by this if you write code on a lenient platform, and later run it on a strict platform:
mysql> show warnings;
I struggled for some time to utilize mysql's blob column to store images and especially large files with good performance in and out. I found this tutorials implementation very useful: http://www.dreamwerx.net/phpforum/?id=1
Following way we can store blob data in a table using MYSQL:
INSERT INTO PICTABLE (MYID, PIC) VALUES (3, LOAD_FILE('/PHP/ME.JPG'));
Simon Mudd is right, but there are several things that must come together to make this bad:
2 rows in set (0.00 sec)1. You must have a query that has an EXPLAIN which includes 'using temporary'. If 'using temporary' is shown in your EXPLAIN plan, then a temporary table is being created either in MEMORY or as MyISAM table on disk. MySQL prefers MEMORY, but there are situations where it is forced to go to disk.
2. You must have a query which includes any TEXT or BLOB type in the column list, that is in the part of the query between SELECT and FROM. The actual size of the column or its content do not matter - even a TINYTEXT that is empty is enough.
Since the MEMORY storage engine cannot represent any TEXT or BLOB types at all, this forces MySQL to realize the table as an on-disk MyISAM table.
How to diagnose:
1. Run show session status:
kris@localhost [test_world]> show session status like 'Created_tmp%tables';
2. Execute the query. Make sure it is not cached:
kris@localhost [test_world]> select sql_no_cache * from kris group by countrycode order by population;
...
232 rows in set (0.00 sec)
3. Check show status again:
kris@localhost [test_world]> show session status like 'Created_tmp%tables';
2 rows in set (0.00 sec)
As you can see the Created_tmp_tables counter increased by one (in MySQL 5.0 is increases by two because the SHOW STATUS itself creates an in-memory tmp table which is being counted). If the table goes to disk as MyISAM instead of being a MEMORY Table, Created_tmp_disk_tables is also incremented by one, as seen here. This is slow.
The test table I used is using the MySQL world database and
mysql> create table kris as select * from City;
mysql> alter table kris modify column name text;
mysql> alter table kris add primary key (id);
The test query shown above is 'using temporary' because I group by one column and order by another, forcing MySQL to use a temporary table.
Had I been using the same query on the original City table from the world database, a tmp table would have been needed as well, but it would have been created as a MEMORY table as the original name column is a CHAR(35). So Created_tmp_tables is being bumped by one, but Created_tmp_disk_tables is not.
Had I been leaving off the SQL_NO_CACHE, the query cache would have been catching repeated executions of the same query in testing and the counters would not have been moving at all except for the very first test.
I struggled for a while to figure out how to pass the values into binary fields without getting all messed up.
It would seem one things that I don't know, and took me a while to find was that each binary value must be a 2 character hex value. Makes sense, but I didn't think about it at the time.
So for anyone else who is struggling with it; if you are trying to load binary values such as 10,127,10 which is A,7F,A in hex. To insert it in a blob/binary column use x'0A7F0A' . See, just add a 0 infront of anything that is only one character in hex.
This was my first time working with BLOB data, but I first wanted to test WITHOUT an intermediary programming language. (That would add another source of errors, I think.) I had a hard time trying to test inserting and selecting.
Probably this is old had to professional programmers, but my book's limited discussion of BLOB data was about the data type, not how to use it.
Newbies, to make your life easier, here's a quick how-to insert/return blob data at the command line:
****
1) Got errors about NULL value in NOT NULL column. Permissions were fixed as far as I could see (have MySQL installed as a service on Windows 7, and all users had at least read/execute permissions). I did not see any "max_allowed_packet" or "secure_file_priv" already existing in the "my.ini" file.
SOLUTION: In addition to proper permissions, I need to use "/", not "\" in path to blob data (which was a picture). Note, this worked properly even for a non-relative path starting at the drive letter! :D
Meanwhile, I tried moving the photo to a new directory to solve my so-called "permissions" problem, but that wasn't the problem. Truly, I was getting Error 1048 was because I needed to use forward slashes! (You will get Error 1048 if you try to insert a NULL value, or when using LOAD_FILE and it can't read it for any reason...not always permissions.)
2) After solving #1, SELECT statement seemed to confirm the picture is indeed stored in the table. However, this returned so many unreadable characters that I could not scroll back to see the complete results, and I had to wait a couple minutes until my computer stopped beeping. (Lucky for me, the system didn't crash.)
SOLUTION: use the SUBSTRING() function in the SELECT statement to only return so many characters from that blob field!
** SAMPLE DATA IF YOU WANT TO TRY YOURSELF **
** Edited, forgot to use double-backslashes in "Filename" column. **
CREATE TABLE Photos(
PhotoID int unsigned not null auto_increment primary key,
Filename varchar(255) not null unique,
Caption varchar(255) not null,
Photo longblob not null);
DESCRIBE Photos;
INSERT INTO Photos values (
NULL,
'D:\\mytemp\\WOC-logo.jpg',
'Walk of Champions official logo',
LOAD_FILE('D:/mytemp/WOC-logo.jpg')
);
SELECT PhotoID, Filename, Caption, SUBSTRING(Photo,1,20) from Photos;
This page lists the BLOB and TEXT types and says that they differ only in the sizes that they can hold, but then never states what the different maximum sizes are. Here they are:
TINYTEXT - 255 bytes
TEXT - 65535 bytes
MEDIUMTEXT - 16,777,215 bytes (2^24 - 1)
LONGTEXT - 4G bytes (2^32 – 1)
TINYBLOB - 255 bytes
BLOB - 65535 bytes
MEDIUMBLOB - 16,777,215 bytes (2^24 - 1)
LONGBLOB - 4G bytes (2^32 – 1)
Add your own comment.