CASEvalueWHENcompare_valueTHENresult[WHENcompare_valueTHENresult...] [ELSEresult] ENDCASE WHENconditionTHENresult[WHENconditionTHENresult...] [ELSEresult] ENDThe first
CASEsyntax returns theresultfor the firstcomparison that is true. The second syntax returns the result for the first condition that is true. If no comparison or condition is true, the result aftervalue=compare_valueELSEis returned, orNULLif there is noELSEpart.NoteThe syntax of the
CASEoperator described here differs slightly from that of the SQLCASEstatement described in Section 13.6.5.1, “CASE Statement”, for use inside stored programs. TheCASEstatement cannot have anELSE NULLclause, and it is terminated withEND CASEinstead ofEND.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; -> NULLIf
expr1isTRUE(andexpr1<> 0),expr1IS NOT NULLIF()returnsexpr2. Otherwise, it returnsexpr3.NoteThere is also an
IFstatement, which differs from theIF()function described here. See Section 13.6.5.2, “IF Statement”.If only one of
expr2orexpr3is explicitlyNULL, the result type of theIF()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
expr2orexpr3produce a string, the result is a string.If
expr2andexpr3are both strings, the result is case-sensitive if either string is case-sensitive.If
expr2orexpr3produce a floating-point value, the result is a floating-point value.If
expr2orexpr3produce 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 notNULL,IFNULL()returnsexpr1; otherwise it returnsexpr2.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 orderexpr1,expr2)STRING,REAL, orINTEGER. Consider the case of a table based on expressions or where MySQL must internally store a value returned byIFNULL()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 isVARBINARY(4)(a string type).Returns
NULLifis true, otherwise returnsexpr1=expr2expr1. This is the same asCASE WHEN.expr1=expr2THEN NULL ELSEexpr1ENDThe return value has the same type as the first argument.
mysql> SELECT NULLIF(1,1); -> NULL mysql> SELECT NULLIF(1,2); -> 1NoteMySQL evaluates
expr1twice if the arguments are not equal.