Table 11.17. Encryption Functions
Name | Description |
---|---|
AES_DECRYPT() |
Decrypt using AES |
AES_ENCRYPT() |
Encrypt using AES |
COMPRESS() (v4.1.1) |
Return result as a binary string |
DECODE() |
Decodes a string encrypted using ENCODE() |
DES_DECRYPT() |
Decrypt a string |
DES_ENCRYPT() |
Encrypt a string |
ENCODE() |
Encode a string |
ENCRYPT() |
Encrypt a string |
MD5() |
Calculate MD5 checksum |
OLD_PASSWORD() (v4.1) |
Return the value of the old (pre-4.1) implementation of PASSWORD |
PASSWORD() |
Calculate and return a password string |
SHA1() , SHA()
|
Calculate an SHA-1 160-bit checksum |
UNCOMPRESS() (v4.1.1) |
Uncompress a string compressed |
UNCOMPRESSED_LENGTH() (v4.1.1) |
Return the length of a string before compression |
The encryption and compression functions return binary
strings. For many of these functions, the result might contain
arbitrary byte values. If you want to store these results, use
a column with a VARBINARY
or
BLOB
binary string data type.
This will avoid potential problems with trailing space removal
or character set conversion that would change data values,
such as may occur if you use a nonbinary string data type
(CHAR
,
VARCHAR
,
TEXT
).
Exploits for the MD5 and SHA-1 algorithms have become known. You may wish to consider using one of the other encryption functions described in this section instead.
AES_DECRYPT(
crypt_str
,key_str
)
This function allows decryption of data using the official
AES (Advanced Encryption Standard) algorithm. For more
information, see the description of
AES_ENCRYPT()
.
AES_ENCRYPT()
and
AES_DECRYPT()
allow
encryption and decryption of data using the official AES
(Advanced Encryption Standard) algorithm, previously known
as “Rijndael.” Encoding with a 128-bit key
length is used, but you can extend it up to 256 bits by
modifying the source. We chose 128 bits because it is much
faster and it is secure enough for most purposes.
AES_ENCRYPT()
encrypts a
string and returns a binary string.
AES_DECRYPT()
decrypts the
encrypted string and returns the original string. The input
arguments may be any length. If either argument is
NULL
, the result of this function is also
NULL
.
Because AES is a block-level algorithm, padding is used to encode uneven length strings and so the result string length may be calculated using this formula:
16 × (trunc(string_length
/ 16) + 1)
If AES_DECRYPT()
detects
invalid data or incorrect padding, it returns
NULL
. However, it is possible for
AES_DECRYPT()
to return a
non-NULL
value (possibly garbage) if the
input data or the key is invalid.
You can use the AES functions to store data in an encrypted form by modifying your queries:
INSERT INTO t VALUES (1,AES_ENCRYPT('text','password'));
AES_ENCRYPT()
and
AES_DECRYPT()
can be
considered the most cryptographically secure encryption
functions currently available in MySQL.
Compresses a string and returns the result as a binary
string. This function requires MySQL to have been compiled
with a compression library such as zlib
.
Otherwise, the return value is always
NULL
. The compressed string can be
uncompressed with
UNCOMPRESS()
.
mysql>SELECT LENGTH(COMPRESS(REPEAT('a',1000)));
-> 21 mysql>SELECT LENGTH(COMPRESS(''));
-> 0 mysql>SELECT LENGTH(COMPRESS('a'));
-> 13 mysql>SELECT LENGTH(COMPRESS(REPEAT('a',16)));
-> 15
The compressed string contents are stored the following way:
Empty strings are stored as empty strings.
Nonempty strings are stored as a four-byte length of the
uncompressed string (low byte first), followed by the
compressed string. If the string ends with space, an
extra “.
” character is
added to avoid problems with endspace trimming should
the result be stored in a
CHAR
or
VARCHAR
column. (However,
use of nonbinary string data types such as
CHAR
or
VARCHAR
to store
compressed strings is not recommended anyway because
character set conversion may occur. Use a
VARBINARY
or
BLOB
binary string column
instead.)
Decrypts the encrypted string
crypt_str
using
pass_str
as the password.
crypt_str
should be a string
returned from ENCODE()
.
Encrypt str
using
pass_str
as the password. To
decrypt the result, use
DECODE()
.
The result is a binary string of the same length as
str
.
The strength of the encryption is based on how good the random generator is. It should suffice for short strings.
DES_DECRYPT(
crypt_str
[,key_str
])
Decrypts a string encrypted with
DES_ENCRYPT()
. If an error
occurs, this function returns NULL
.
This function works only if MySQL has been configured with SSL support. See Section 5.5.7, “Using SSL for Secure Connections”.
If no key_str
argument is given,
DES_DECRYPT()
examines the
first byte of the encrypted string to determine the DES key
number that was used to encrypt the original string, and
then reads the key from the DES key file to decrypt the
message. For this to work, the user must have the
SUPER
privilege. The key file
can be specified with the
--des-key-file
server option.
If you pass this function a
key_str
argument, that string is
used as the key for decrypting the message.
If the crypt_str
argument does
not appear to be an encrypted string, MySQL returns the
given crypt_str
.
DES_ENCRYPT(
str
[,{key_num
|key_str
}])
Encrypts the string with the given key using the Triple-DES algorithm.
This function works only if MySQL has been configured with SSL support. See Section 5.5.7, “Using SSL for Secure Connections”.
The encryption key to use is chosen based on the second
argument to DES_ENCRYPT()
, if
one was given. With no argument, the first key from the DES
key file is used. With a key_num
argument, the given key number (0–9) from the DES key
file is used. With a key_str
argument, the given key string is used to encrypt
str
.
The key file can be specified with the
--des-key-file
server option.
The return string is a binary string where the first
character is CHAR(128 |
. If an error
occurs, key_num
)DES_ENCRYPT()
returns
NULL
.
The 128 is added to make it easier to recognize an encrypted
key. If you use a string key,
key_num
is 127.
The string length for the result is given by this formula:
new_len
=orig_len
+ (8 - (orig_len
% 8)) + 1
Each line in the DES key file has the following format:
key_num
des_key_str
Each key_num
value must be a
number in the range from 0
to
9
. Lines in the file may be in any order.
des_key_str
is the string that is
used to encrypt the message. There should be at least one
space between the number and the key. The first key is the
default key that is used if you do not specify any key
argument to DES_ENCRYPT()
.
You can tell MySQL to read new key values from the key file
with the FLUSH
DES_KEY_FILE
statement. This requires the
RELOAD
privilege.
One benefit of having a set of default keys is that it gives applications a way to check for the existence of encrypted column values, without giving the end user the right to decrypt those values.
mysql>SELECT customer_address FROM customer_table
>WHERE crypted_credit_card = DES_ENCRYPT('credit_card_number');
Encrypts str
using the Unix
crypt()
system call and returns a
binary string. The salt
argument
should be a string with at least two characters. If no
salt
argument is given, a random
value is used.
mysql> SELECT ENCRYPT('hello');
-> 'VxuFAJXVARROc'
ENCRYPT()
ignores all but the
first eight characters of str
, at
least on some systems. This behavior is determined by the
implementation of the underlying
crypt()
system call.
The use of ENCRYPT()
with
multi-byte character sets other than utf8
is not recommended because the system call expects a string
terminated by a zero byte.
If crypt()
is not available on your
system (as is the case with Windows),
ENCRYPT()
always returns
NULL
.
Calculates an MD5 128-bit checksum for the string. The value
is returned as a binary string of 32 hex digits, or
NULL
if the argument was
NULL
. The return value can, for example,
be used as a hash key.
mysql> SELECT MD5('testing');
-> 'ae2b1fca515949e5d54fb22b8ed95575'
This is the “RSA Data Security, Inc. MD5 Message-Digest Algorithm.”
If you want to convert the value to uppercase, see the
description of binary string conversion given in the entry
for the BINARY
operator in
Section 11.9, “Cast Functions and Operators”.
See the note regarding the MD5 algorithm at the beginning this section.
OLD_PASSWORD()
was added to
MySQL when the implementation of
PASSWORD()
was changed to
improve security.
OLD_PASSWORD()
returns the
value of the old (pre-4.1) implementation of
PASSWORD()
as a binary
string, and is intended to permit you to reset passwords for
any pre-4.1 clients that need to connect to your version
5.1 MySQL server without locking them out. See
Section 5.5.6.3, “Password Hashing in MySQL”.
Calculates and returns a password string from the plaintext
password str
and returns a binary
string, or NULL
if the argument was
NULL
. This is the function that is used
for encrypting MySQL passwords for storage in the
Password
column of the
user
grant table.
mysql> SELECT PASSWORD('badpwd');
-> '*AAB3E285149C0135D51A520E1940DD3263DC008C'
PASSWORD()
encryption is
one-way (not reversible).
PASSWORD()
does not perform
password encryption in the same way that Unix passwords are
encrypted. See ENCRYPT()
.
The PASSWORD()
function is
used by the authentication system in MySQL Server; you
should not use it in your own
applications. For that purpose, consider
MD5()
or
SHA1()
instead. Also see
RFC
2195, section 2 (Challenge-Response Authentication
Mechanism (CRAM)), for more information about
handling passwords and authentication securely in your
applications.
Calculates an SHA-1 160-bit checksum for the string, as
described in RFC 3174 (Secure Hash Algorithm). The value is
returned as a binary string of 40 hex digits, or
NULL
if the argument was
NULL
. One of the possible uses for this
function is as a hash key. You can also use it as a
cryptographic function for storing passwords.
SHA()
is
synonymous with SHA1()
.
mysql> SELECT SHA1('abc');
-> 'a9993e364706816aba3e25717850c26c9cd0d89d'
SHA1()
can be considered a
cryptographically more secure equivalent of
MD5()
. However, see the note
regarding the MD5 and SHA-1 algorithms at the beginning this
section.
UNCOMPRESS(
string_to_uncompress
)
Uncompresses a string compressed by the
COMPRESS()
function. If the
argument is not a compressed value, the result is
NULL
. This function requires MySQL to
have been compiled with a compression library such as
zlib
. Otherwise, the return value is
always NULL
.
mysql>SELECT UNCOMPRESS(COMPRESS('any string'));
-> 'any string' mysql>SELECT UNCOMPRESS('any string');
-> NULL
UNCOMPRESSED_LENGTH(
compressed_string
)
Returns the length that the compressed string had before being compressed.
mysql> SELECT UNCOMPRESSED_LENGTH(COMPRESS(REPEAT('a',30)));
-> 30
User Comments
Complicated but interesting...
This assumes MySQL has been configured with SSL support [ ./configure --with-openssl ]
CREATE TABLE password (
p_id int(11) NOT NULL auto_increment,
id varchar(20),
valid enum('y','n'),
password BLOB,
timeEnter timestamp,
PRIMARY KEY (p_id)
);
insert into password (id,password)
values ('bob',des_encrypt('secret','somekey'));
insert into password (id,password)
values ('tom',des_encrypt('password','somekey'));
insert into password (id,password)
values ('kate',des_encrypt('desmark','somekey'));
insert into password (id,password)
values ('tim',des_encrypt('tim','somekey'));
insert into password (id,password)
values ('sue',des_encrypt('SUM','somekey'));
insert into password (id,password)
values ('john',des_encrypt('dotgo86','somekey'));
insert into password (id)
values ('randal');
mysql> select id,des_decrypt(password,'somekey') from password;
+--------+---------------------------------+
| id | des_decrypt(password,'somekey') |
+--------+---------------------------------+
| bob | secret |
| tom | password |
| kate | desmark |
| tim | tim |
| sue | SUM |
| john | dotgo86 |
| randal | NULL |
+--------+---------------------------------+
7 rows in set (0.00 sec)
Note the bad passwords in the file ('secret','password', and
password is the same as the id.
The following update statement will fill in the
value for valid:
update password set valid =
COALESCE(
concat(
substring('y',1,
1-sign(abs(
find_in_set( lcase( des_decrypt(password,'somekey'))
,concat('password,secret,simple,',lcase(id),',test'))))
),
substring('n',1,
sign(abs(
find_in_set( lcase( des_decrypt(password,'somekey'))
,concat('password,secret,simple,',lcase(id),',test'))))
)
)
,'n');
Which gives the following:
mysql> select id,valid from password;
select id,valid from password;
+--------+-------+
| id | valid |
+--------+-------+
| bob | n |
| tom | n |
| kate | y |
| tim | n |
| sue | y |
| john | y |
| randal | n |
+--------+-------+
7 rows in set (0.00 sec)
To understand it, try taking the following select apart:
select
COALESCE(
concat(
substring('y',1,
1-sign(abs(
find_in_set( lcase( des_decrypt(password,'somekey'))
,concat('password,secret,simple,',lcase(id),',test'))))
),
substring('n',1,
sign(abs(
find_in_set( lcase( des_decrypt(password,'somekey'))
,concat('password,secret,simple,',lcase(id),',test'))))
)
)
,'n')
as valid
from password;
Reference:
http://osdn.dl.sourceforge.net/sourceforge/souptonuts/README_mysql.txt
Regards,
Mike Chirico
Are you having trouble decrypting your information?
If so, be sure that your field sizes are properly set for the type of encryption algorithim you've chosen. Otherwise, the encrypted data will be truncated, and of course, decryption will fail.
For instance, you'll need to have a field size of at least 40 characters to successfully store a string encoded with SHA1.
before storing an AES key to the server, please investigate whether it will be swapped out to disk on that server or not (http://bugs.mysql.com/bug.php?id=7846)
Note,
ENCODE and DECODE don't seem to accept a row name as the second argument. so the following WILL FAIL:
select * from `table_name` where `encrypted_row` = ENCODE('passed_value',`salt_row`)
however, the first argument can be a row name, as follows:
select * from `table_name` where `encrypted_row` = ENCODE(`salt_row`,'passed_value')
The first example of using md5 to store passwords to a web app is not ideal. It is vulnerable to dictonary attacks.
For a start, the users password may pass over the network (if your web app and mysql server are on different machines). If you're not using SSL to mysql, then this will be in plain text. PHP has an md5 function, it may be better to use that (especially if this is a secure web app running over SSL).
If I were to get a dump of your password table, and I had a list of pre-computed md5 sums for possible passwords, i could quite easily do a compare to see if any user has a password in my list.
The way the UNIX password file (now) does it is to add some 'salt' to the password. You add an extra field to your password table, 'salt'. This is a random string (generated each time the user changes their password). This salt is stored in plain text. When you are computing the md5 of the password, you prepend (or append, it doesn't matter - as long as you're consistent) the salt to the password. e.g. md5($salt . $password). When they try to log in, you do the same thing md5($salt . $entered_password). If that equals the value of the password field in the database, you allow access!
this means that if an attacker gets a dump of your password table, they are going to have to get their list of passwords and md5 sum every single one with every single salt value (in your table) to do a dictionary attack.
Instantly you now have better security!
If I understand correctly that the keys to all these algorithms are sent in plain text to the SQL server so that it can perform the crypto then using any of these is insanely dangerous.
Most likely your keys will end up in update logs, packet sniffer logs, replication logs, error logs....who knows.
Do the crypto in your application before inserting and after selecting. THERE SHOULD BE A BIG WARNING ABOUT THIS.
AES_ENCRYPT: if strlen(str) % 16 == 0 then AES_ENCRYPT will add an axtra block of chr(16). This is particularly useful to know when trying to use PHP's mcrypt.
That's totally correct about the use of SQL encryption functions. If you don't use a localhost or SSL connection to your database server, the plaintext and key string are sent in the clear and encryption does not protect any data from attackers along that path.
One way to protect more sensitive information, for instance, credit card numbers, is to use GnuPG to encrypt the data with the public part of a key whose private counterpart only lives on a very secure machine that runs the batch transaction, and requires a passphrase to load it into memory in your charging program. The encrypted block is stored in a text field, the plaintext never crosses the network, and an attack on the web server or database cannot compromise the data.
The slightly stronger exception might be the use of DES_ENCRYPT, which if you have configured your keyring on your server, does not need to transmit the locking key with the plaintext data. (Though it still transmits the plaintext in the clear.)
Also, regarding the mentioned exploit of sha1, there are stronger versions like sha256, sha384, sha512 etc. but mysql does not implement them; they would have to be implemented in code.
1 row in set (0.01 sec)I had problems with ENCRYPT MySQL function when i tried to compare with the encrypted password (with ENCRYPT).
Another solution i read from "UNIX Advanced programming" where i found about the UNIX system call "crypt()":
Password="tB" //The two first letters of encrypted password
SELECT password from users where Password=ENCRYPT('".$_POST['password']."',Password)
mysql> select password from users where password=encrypt('pasword','tB');
Bye.
Answer from: http://es2.php.net/manual/es/function.crypt.php
> topace at lightbox dot org
> 22-Sep-2005 06:34
>
> To authenticate against a stored crypt in MySQL, simply use:
>
> SELECT ................
> AND Password=ENCRYPT('".$_POST['password']."',Password)
If you've implemented SSL, see...
http://dev.mysql.com/doc/refman/5.0/en/secure-create-certs.html
...you can use Triggers and DES_ENCRYPT to move your password encryption to the database level and enforce it in a way that stops developers forgeting to use it (or bypassing it) with the following triggers...
CREATE TRIGGER user_insert BEFORE INSERT ON `user` FOR EACH ROW SET NEW.TimeStampCreated = NOW(), NEW.Password = DES_ENCRYPT(NEW.Password);
CREATE TRIGGER user_update BEFORE UPDATE ON `user` FOR EACH ROW SET NEW.Password = DES_ENCRYPT(NEW.Password);
...you'll also notice the first one enforces auditing in a way that saves you from relying on developers getting that right as well.
You could give your dev's a nice stored proc to retrieve or comapre their submitted password but hopefully they can remember either DES_ENCRYPT/_DECRYPT or your phone number ;^).
Whilst bearing in mind that this doesn't magically make your entire system "secure" by some magic wave of a wand, given that you've implemented SSL it should be trivial to secure the link between web and database server (if there even is a gap) and then you can use HTTPS and only a little more careful thought to implement a system that is secure from submission page through to backup system in such a way that only someone physically stood at the server with the server's and Mysql's root password could decrypt the password/data.
If you are using MySQL to store any sort of encrypted credit card information, note that you will want NOT want to do the encryption using the built in encryption functions, as encryption key AND the CLEAR TEXT VERSION OF THE DATA will end up in your replication logs, and possibly error logs. Do your encryption in your application.
As noted in Bug #16713 (AES_Encrypt / AES_Decrypt functions is low documented), the full specs of the encryption function are not given, so Steve Brendtro's suggestion made it difficult to implement a client side AES_ENCRYPT method.
It took a lot of searching to come across the bug report whilst trying to find the option when using the MS .Net RijndaelManaged methods, so I thought I'd share the code:
public byte[] AESEncrypt(byte[] plaintext, byte[] key) {
/* Simulate MySQL AES_ENCRYPT function
* Block Length: 128bit
* Block Mode: ECB
* Data Padding: Padded by bytes which Asc() equal for number of padded bytes (done automagically)
* Key Padding: 0x00 padded to multiple of 16 bytes
* IV: None
*/
RijndaelManaged aes = new RijndaelManaged();
aes.BlockSize = 128;
aes.Mode = CipherMode.ECB;
aes.Key = key;
// Create the Encrypter & streams needed
ICryptoTransform encryptor = aes.CreateEncryptor();
MemoryStream mem = new MemoryStream();
CryptoStream cryptStream = new CryptoStream(mem, encryptor,
CryptoStreamMode.Write);
// Write the Plaintext & flush
cryptStream.Write(plaintext, 0, plaintext.Length);
cryptStream.FlushFinalBlock();
// Get the encrypted bytes
byte[] cypher = mem.ToArray();
// Tidy up
cryptStream.Close();
cryptStream = null;
encryptor.Dispose();
aes = null;
return cypher;
}
Hopefully this will help anyone who's been trying to get around this issue.
Shorter MD5 :) here in my idea:
In a MySQL function:
declare $s char(32);
set $s=md5($word);
return concat(conv(substr($s,1,16),16,36),'x',conv(substr($s,17),16,36));
'x' must be a char which is not in result of conv()!!!
'x' must NOT be 0-9 and A-Z ! For example '-' is also good.
It is nice, not much slower then alone md5 function.
Length of this is 25-27 characters instead of 32.
(Max. 27 (2x13+1) because length of conv('FFFFFFFFFFFFFFFF',16,36) is 13!)
MySQL UNCOMPRESS sans MySQL - yes, generic *n*x tools can recover the data.
Using only non-MySQL tools:
wget http://www.zlib.net/zpipe.c
gcc -o zpipe zpipe.c -lz
mysql -B -e "SELECT HEX(COMPRESS('Test data!'))" | xxd -r -ps | dd bs=1 skip=4 2>/dev/null | ./zpipe -d; echo
Test data!
Wrap it with HEX (mysql is binary-unsafe)
and unwrap it with xxd
then drop the header with dd
and uncompress with zpipe, i.e.,
(0) start with the string 'Test data!'
(1) COMPRESS compresses it to binary
(2) HEX renders it to text
(3) xxd reverts it to binary
(4) dd discards the UNCOMPRESSED_LENGTH header
(5) zpipe uncompresses the rest
(6) echo adds a newline
Repeat using MySQL:
mysql -B -e "SELECT HEX(COMPRESS('Test data!'))" | tail +2 | mysql -B -e "SELECT UNCOMPRESS(UNHEX('`cat`'))" | tail +2
Test data!
i.e.,
(7) same as 0-2
(8) tail discards the echoed SQL command
(9) cat obtains the piped data
(10) UNHEX same as 3
(11) UNCOMPRESS same as 4-5
(12) tail same as 8
Nice to have the added safety of a second source.
One of the main benefits of the encryption features in MySQL, as opposed to in the language of your choice, is that Stored Procedures can be used to perform encryption without exposing keys to the client. At http://www.duofertility.com we transmit medical data between client and database, for example, so secure authentication is critical - however cryptographic authentication is not included in MySQL natively.
However the below implements HMAC-MD5 with 128-bit keys (see FRC2104) as a Stored Procedure. The keytable has "id" and "key", the calling code simply passes the "id" and the message to HMACMD5, and is returned the HMAC as a binary string. Access to the keytable must be limited, but access to call HMAC-MD5 can be given out freely.
Modifying the size of the key and the hash function would yield HMAC-SHA1, however beware that binary XOR only operates on up to 64 bit values, hence the convoluted ipad/opad generation.
DELIMITER //
CREATE PROCEDURE HMACMD5(IN keynumber INTEGER, IN message BLOB, OUT output BINARY(16))
BEGIN
DECLARE ipad,opad BINARY(64);
DECLARE hexkey CHAR(32);
SELECT LPAD(HEX(`key`),32,"0") INTO hexkey FROM `keytable` WHERE `id` = keynumber;
SET ipad = UNHEX(CONCAT(LPAD(RIGHT(CONV(CONV( MID(hexkey,1,11) , 16, 10 ) ^ CONV( '36363636363', 16, 10 ),10,16),11),11,"0"),
LPAD(RIGHT(CONV(CONV( MID(hexkey,12,11) , 16, 10 ) ^ CONV( '63636363636' , 16, 10 ),10,16),11),11,"0"),
LPAD(RIGHT(CONV(CONV( MID(hexkey,23,10) , 16, 10 ) ^ CONV( '3636363636' , 16, 10 ),10,16),10),10,"0"),'363636363636363636363636363636363636363636363636363636363636363636363636363636363636363636363636'));
SET opad = UNHEX(CONCAT(LPAD(RIGHT(CONV(CONV( MID(hexkey,1,11) , 16, 10 ) ^ CONV( '5c5c5c5c5c5', 16, 10 ),10,16),11),11,"0"),
LPAD(RIGHT(CONV(CONV( MID(hexkey,12,11) , 16, 10 ) ^ CONV( 'c5c5c5c5c5c' , 16, 10 ),10,16),11),11,"0"),
LPAD(RIGHT(CONV(CONV( MID(hexkey,23,10) , 16, 10 ) ^ CONV( '5c5c5c5c5c' , 16, 10 ),10,16),10),10,"0"),'5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c5c'));
SET output = UNHEX(MD5(CONCAT(opad,UNHEX(MD5(CONCAT(ipad,message))))));
END //
DELIMITER ;
Add your own comment.