- CASE- valueWHEN- compare_valueTHEN- result[WHEN- compare_valueTHEN- result...] [ELSE- result] END- CASE WHEN- conditionTHEN- result[WHEN- conditionTHEN- result...] [ELSE- result] END- The first - CASEsyntax returns the- resultfor the first- value=- compare_value- ELSEis returned, or- NULLif there is no- ELSEpart.Note- The syntax of the - CASEoperator described here differs slightly from that of the SQL- CASEstatement described in Section 13.6.5.1, “CASE Statement”, for use inside stored programs. The- CASEstatement cannot have an- ELSE NULLclause, and it is terminated with- END CASEinstead of- END.- The return type of a - CASEexpression result is the aggregated type of all result values.- mysql> SELECT CASE 1 WHEN 1 THEN 'one' -> WHEN 2 THEN 'two' ELSE 'more' END; -> 'one' mysql> SELECT CASE WHEN 1>0 THEN 'true' ELSE 'false' END; -> 'true' mysql> SELECT CASE BINARY 'B' -> WHEN 'a' THEN 1 WHEN 'b' THEN 2 END; -> NULL
- If - expr1is- TRUE(- expr1<> 0- expr1IS NOT NULL- IF()returns- expr2. Otherwise, it returns- expr3.Note- There is also an - IFstatement, which differs from the- IF()function described here. See Section 13.6.5.2, “IF Statement”.- If only one of - expr2or- expr3is explicitly- NULL, the result type of the- IF()function is the type of the non-- NULLexpression.- The default return type of - IF()(which may matter when it is stored into a temporary table) is calculated as follows:- If - expr2or- expr3produce a string, the result is a string.- If - expr2and- expr3are both strings, the result is case-sensitive if either string is case-sensitive.
- If - expr2or- expr3produce a floating-point value, the result is a floating-point value.
- If - expr2or- expr3produce an integer, the result is an integer.
 - mysql> SELECT IF(1>2,2,3); -> 3 mysql> SELECT IF(1<2,'yes','no'); -> 'yes' mysql> SELECT IF(STRCMP('test','test1'),'no','yes'); -> 'no'
- If - expr1is not- NULL,- IFNULL()returns- expr1; otherwise it returns- expr2.- mysql> SELECT IFNULL(1,0); -> 1 mysql> SELECT IFNULL(NULL,10); -> 10 mysql> SELECT IFNULL(1/0,10); -> 10 mysql> SELECT IFNULL(1/0,'yes'); -> 'yes'- The default return type of - IFNULL(is the more “general” of the two expressions, in the order- expr1,- expr2)- STRING,- REAL, or- INTEGER. Consider the case of a table based on expressions or where MySQL must internally store a value returned by- IFNULL()in a temporary table:- mysql> CREATE TABLE tmp SELECT IFNULL(1,'test') AS test; mysql> DESCRIBE tmp; +-------+--------------+------+-----+---------+-------+ | Field | Type | Null | Key | Default | Extra | +-------+--------------+------+-----+---------+-------+ | test | varbinary(4) | NO | | | | +-------+--------------+------+-----+---------+-------+- In this example, the type of the - testcolumn is- VARBINARY(4)(a string type).
- Returns - NULLif- expr1=- expr2- expr1. This is the same as- CASE WHEN.- expr1=- expr2THEN NULL ELSE- expr1END- The return value has the same type as the first argument. - mysql> SELECT NULLIF(1,1); -> NULL mysql> SELECT NULLIF(1,2); -> 1Note- MySQL evaluates - expr1twice if the arguments are not equal.