Table 11.13. Cast Functions
Name | Description |
---|---|
BINARY |
Cast a string to a binary string |
CAST() |
Cast a value as a certain type |
Convert() |
Cast a value as a certain type |
The BINARY
operator casts the
string following it to a binary string. This is an easy way to
force a column comparison to be done byte by byte rather than
character by character. This causes the comparison to be case
sensitive even if the column isn't defined as
BINARY
or
BLOB
.
BINARY
also causes trailing
spaces to be significant.
mysql>SELECT 'a' = 'A';
-> 1 mysql>SELECT BINARY 'a' = 'A';
-> 0 mysql>SELECT 'a' = 'a ';
-> 1 mysql>SELECT BINARY 'a' = 'a ';
-> 0
In a comparison, BINARY
affects
the entire operation; it can be given before either operand
with the same result.
BINARY
is shorthand for
str
CAST(
.
str
AS
BINARY)
Note that in some contexts, if you cast an indexed column to
BINARY
, MySQL is not able to use the index
efficiently.
The CAST()
function takes a
value of one type and produce a value of another type, similar
to CONVERT()
. See the
description of CONVERT()
for
more information.
CONVERT(
,
expr
,type
)CONVERT(
expr
USING transcoding_name
)
The CONVERT()
and
CAST()
functions take a value
of one type and produce a value of another type.
The type
can be one of the
following values:
BINARY
produces a string with
the BINARY
data type. See
Section 10.4.2, “The BINARY
and
VARBINARY
Types” for a description of how
this affects comparisons. If the optional length
N
is given,
BINARY(
causes
the cast to use no more than N
)N
bytes of the argument. Values shorter than
N
bytes are padded with
0x00
bytes to a length of
N
.
CHAR(
causes the cast to use no more than
N
)N
characters of the argument.
CAST()
and
CONVERT(... USING ...)
are
standard SQL syntax. The non-USING
form of
CONVERT()
is ODBC syntax.
CONVERT()
with
USING
is used to convert data between
different character sets. In MySQL, transcoding names are the
same as the corresponding character set names. For example,
this statement converts the string 'abc'
in
the default character set to the corresponding string in the
utf8
character set:
SELECT CONVERT('abc' USING utf8);
Normally, you cannot compare a BLOB
value or other binary string in case-insensitive fashion because
binary strings have no character set, and thus no concept of
lettercase. To perform a case-insensitive comparison, use the
CONVERT()
function to convert the
value to a nonbinary string. If the character set of the result
has a case-insensitive collation, the
LIKE
operation is not case sensitive:
SELECT 'A' LIKE CONVERT(blob_col
USING latin1) FROMtbl_name
;
To use a different character set, substitute its name for
latin1
in the preceding statement. To ensure
that a case-insensitive collation is used, specify a
COLLATE
clause following the
CONVERT()
call.
CONVERT()
can be used more
generally for comparing strings that are represented in different
character sets.
The cast functions are useful when you want to create a column
with a specific type in a
CREATE TABLE ...
SELECT
statement:
CREATE TABLE new_table SELECT CAST('2000-01-01' AS DATE);
The functions also can be useful for sorting
ENUM
columns in lexical order.
Normally, sorting of ENUM
columns
occurs using the internal numeric values. Casting the values to
CHAR
results in a lexical sort:
SELECTenum_col
FROMtbl_name
ORDER BY CAST(enum_col
AS CHAR);
CAST(
is the same thing as
str
AS
BINARY)BINARY
.
str
CAST(
treats the expression as a string with the default
character set.
expr
AS
CHAR)
CAST()
also changes the result if
you use it as part of a more complex expression such as
CONCAT('Date: ',CAST(NOW() AS
DATE))
.
You should not use CAST()
to
extract data in different formats but instead use string functions
like LEFT()
or
EXTRACT()
. See
Section 11.6, “Date and Time Functions”.
To cast a string to a numeric value in numeric context, you normally do not have to do anything other than to use the string value as though it were a number:
mysql> SELECT 1+'1';
-> 2
If you use a number in string context, the number automatically is
converted to a BINARY
string.
mysql> SELECT CONCAT('hello you ',2);
-> 'hello you 2'
MySQL supports arithmetic with both signed and unsigned 64-bit
values. If you are using numeric operators (such as
+
or
-
) and one of the
operands is an unsigned integer, the result is unsigned. You can
override this by using the SIGNED
and
UNSIGNED
cast operators to cast the operation
to a signed or unsigned 64-bit integer, respectively.
mysql>SELECT CAST(1-2 AS UNSIGNED)
-> 18446744073709551615 mysql>SELECT CAST(CAST(1-2 AS UNSIGNED) AS SIGNED);
-> -1
Note that if either operand is a floating-point value, the result
is a floating-point value and is not affected by the preceding
rule. (In this context, DECIMAL
column values are regarded as floating-point values.)
mysql> SELECT CAST(1 AS UNSIGNED) - 2.0;
-> -1.0
If you are using a string in an arithmetic operation, this is converted to a floating-point number.
If you convert a “zero” date string to a date,
CONVERT()
and
CAST()
return
NULL
and produce a warning when the
NO_ZERO_DATE
SQL mode is
enabled.
User Comments
Be careful that this 'feature' of MySQL dosn't bit you in the ass.
For example, imagine I have a table with two 'unsigned' integer columns (still with me?). Lets call those columns 'one' and 'two'. Now imagine the following query...
# Query to select the 10 biggest differences between two colums
SELECT one - two AS diff
ORDER BY one - two
LIMIT 10;
If the result of 'one - two' is negative (imagine that the value of two is bigger than one), then you end up with values of 18446744073709551615.
This isn't a bug mind you, as this fact is documented this is the expected behaviour!
So, still looking for the 10 biggest differences you might try...
# Query 2 to select the 10 biggest differences between two colums
SELECT one - two AS diff
WHERE one - two < 10000 -- Hopefuly bigger than our biggest differences
ORDER BY one - two
LIMIT 10;
You find it dosn't work, (you still get the 18446744073709551615s) because the internals of subtracting unsigned columns are so messed up.
You need to do the following...
# Query 3 to select the 10 biggest differences between two colums
SELECT CAST(one - two AS SIGNED) AS diff
ORDER BY diff
LIMIT 10;
I hope this example helps
To convert to numeric, the convert() and cast() functions are less forgiving then the implicit conversion when it comes to the data to be converted. If you want to convert "1a" or "1 apple", "2 apples", " 3 things" to 1, 1, 2 and 3 respectivly, the cast and convert function will produce an error. Instead use select 0+'1a', 0+'1 apple', 0+'2 apples', 0+' 3 things'.
Here's a workaround for not being able to cast/convert a value during table creation with just a create:
CREATE TEMPORARY TABLE tmp
SELECT 1000000.001-1000000.001 as n;
This will yield a table with the following structure:
The cast() function is amazingly useful when working with dates - not to mention date+time.
First, take a look at the following basic example:
select cast('2007-12-25' as DATETIME)
This naturally returns the output:
2007-12-25 00:00:00
But there are REALLY useful practical situations where we'd HAVE to use this function. Here's a case:
I want to pick all records from a table "Sales", where the "TransactionDate" field is between 25-Dec-2007 and 25-Jan-2008. Bear in mind that the field is of type DateTime.
Here's the BASIC query that I'd put in a string if I were to do it in PHP:
"SELECT * FROM Sales WHERE TransactionDate BETWEEN '$D1' and $D2"
In the above case, I'm assuming that $D1 and $D2 are posted variables in PHP. Unfortunately The above line won't work. And THIS is where we can use the CAST() function.
So here's the CORRECT STATEMENT:
"SELECT * FROM Sales WHERE TransactionDate BETWEEN CAST('$D1' as DATETIME) and CAST($D2 as DATETIME)"
This does the job without a flaw!
Happy programming,
Khalid
Alphanumeric strings automatically evaluate to 0 when used in a SELECT query to match against a column of type INT.
For example:
Table T1
n: INT
n_squared: INT,
n n_squared
0 0
1 1
2 4
3 9
4 16
...
Q1: SELECT * FROM T1 WHERE n_squared='ABC';
Q2: SELECT * FROM T1 WHERE n_squared='ABC123';
Both queries produce identical results:
n n_squared
0 0
MySQL 5.1 returns a 64-bit integer when using CAST(). For those looking to cast a 32-bit signed integer to a 32-bit unsigned integer: you can use the function this way.
Converting -1062731519 to an unsigned integer (this number is the decimal value of 192.168.1.1):
SELECT CAST(('-1062731519' & 0xFFFFFFFF) AS UNSIGNED INTEGER);
Result is 3232235903, which is correct.
To save others time in searching for something that wasn't immediately obvious to me...
A list of character sets is in 9.1.12. Character Sets and Collations That MySQL Supports, http://dev.mysql.com/doc/refman/5.0/en/charset-charsets.html
Here's another workaround for the lack of data types: create your own conversion function. I am working with a DB (unfortunately) converted from and used by MS Access. All the primary keys are therefor of type INT(10) SIGNED. When UNIONing a constant integer (SELECT 0 AS Key) with a queried value the result is of the wrong type. So, since "CAST(0 AS INT(10))" is not an option I created my own:
CREATE FUNCTION `IntToInt10`(TheInt INT)
RETURNS INT(10) SIGNED -- here is the trick
DETERMINISTIC
BEGIN
RETURN TheInt;
END
Now, whenever I need to force a result to be of type int(10) I just run it through this function. I'm sure it would work for other types too (although a bit more involved if converting between two different classes of data such as numeric to alpha). Hope that helps.
Add your own comment.