Documentation Home
MySQL 8.0 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 38.1Mb
PDF (A4) - 38.1Mb
PDF (RPM) - 33.0Mb
HTML Download (TGZ) - 8.1Mb
HTML Download (Zip) - 8.1Mb
HTML Download (RPM) - 7.0Mb
Man Pages (TGZ) - 132.7Kb
Man Pages (Zip) - 189.0Kb
Info (Gzip) - 3.4Mb
Info (Zip) - 3.4Mb
Excerpts from this Manual

MySQL 8.0 Reference Manual  /  Functions and Operators  /  Control Flow Functions

12.4 Control Flow Functions

Table 12.6 Flow Control Operators

Name Description
CASE Case operator
IF() If/else construct
IFNULL() Null if/else construct
NULLIF() Return NULL if expr1 = expr2

  • CASE value WHEN [compare_value] THEN result [WHEN [compare_value] THEN result ...] [ELSE result] END

    CASE WHEN [condition] THEN result [WHEN [condition] THEN result ...] [ELSE result] END

    The first CASE syntax returns the result for the first value=compare_value comparison 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 after ELSE is returned, or NULL if there is no ELSE part.

    Note

    The syntax of the CASE expression described here differs slightly from that of the SQL CASE statement described in Section 13.6.5.1, “CASE Syntax”, for use inside stored programs. The CASE statement cannot have an ELSE NULL clause, and it is terminated with END CASE instead of END.

    The return type of a CASE expression result is the aggregated type of all result values:

    • If all types are numeric, the aggregated type is also numeric:

      • If at least one argument is double precision, the result is double precision.

      • Otherwise, if at least one argument is DECIMAL, the result is DECIMAL.

      • Otherwise, the result is an integer type (with one exception):

        • If all integer types are all signed or all unsigned, the result is the same sign and the precision is the highest of all specified integer types (that is, TINYINT, SMALLINT, MEDIUMINT, INT, or BIGINT).

        • If there is a combination of signed and unsigned integer types, the result is signed and the precision may be higher. For example, if the types are signed INT and unsigned INT, the result is signed BIGINT.

        • The exception is unsigned BIGINT combined with any signed integer type. The result is DECIMAL with sufficient precision and scale 0.

    • If all types are BIT, the result is BIT. Otherwise, BIT arguments are treated similar to BIGINT.

    • If all types are YEAR, the result is YEAR. Otherwise, YEAR arguments are treated similar to INT.

    • If all types are character string (CHAR or VARCHAR), the result is VARCHAR with maximum length determined by the longest character length of the operands.

    • If all types are character or binary string, the result is VARBINARY.

    • SET and ENUM are treated similar to VARCHAR; the result is VARCHAR.

    • If all types are JSON, the result is JSON.

    • If all types are temporal, the result is temporal:

    • If all types are GEOMETRY, the result is GEOMETRY.

    • If any type is BLOB, the result is BLOB.

    • For all other type combinations, the result is VARCHAR.

    • Literal NULL operands are ignored for type aggregation.

    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(expr1,expr2,expr3)

    If expr1 is TRUE (expr1 <> 0 and expr1 <> NULL), IF() returns expr2. Otherwise, it returns expr3.

    Note

    There is also an IF statement, which differs from the IF() function described here. See Section 13.6.5.2, “IF Syntax”.

    If only one of expr2 or expr3 is explicitly NULL, the result type of the IF() function is the type of the non-NULL expression.

    The default return type of IF() (which may matter when it is stored into a temporary table) is calculated as follows:

    • If expr2 or expr3 produce a string, the result is a string.

      If expr2 and expr3 are both strings, the result is case-sensitive if either string is case sensitive.

    • If expr2 or expr3 produce a floating-point value, the result is a floating-point value.

    • If expr2 or expr3 produce 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'
  • IFNULL(expr1,expr2)

    If expr1 is 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(expr1,expr2) is the more general of the two expressions, in the order 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 test column is VARBINARY(4) (a string type).

  • NULLIF(expr1,expr2)

    Returns NULL if expr1 = expr2 is true, otherwise returns expr1. This is the same as CASE WHEN expr1 = expr2 THEN NULL ELSE expr1 END.

    The return value has the same type as the first argument.

    mysql> SELECT NULLIF(1,1);
            -> NULL
    mysql> SELECT NULLIF(1,2);
            -> 1
    Note

    MySQL evaluates expr1 twice if the arguments are not equal.


User Comments
User comments in this section are, as the name implies, provided by MySQL users. The MySQL documentation team is not responsible for, nor do they endorse, any of the information provided here.
  Posted by sebastian nielsen on September 12, 2010
Milan: How is it useful to run:

SELECT * FROM table WHERE IFNULL(NULL, field = 1)

instead of:

SELECT * FROM table WHERE field = 1

the IFNULL(NULL, field = 1) would always return field = 1.

But the IFNULL() is good in cases you want to do a insert and clamp a value to a value that is already in record, else set it at maximum.

For example this:

INSERT INTO users (type,class,username,userid,userip,usermobile,useremail,daysleft,pin1,pin2,pin3,active,schoolname,schoolsite) SELECT 'A','A','sebastian',1000,'192.168.0.1','none','email@server.se',(SELECT IFNULL(MIN(daysleft),30) from users WHERE userip='192.168.0.1' AND type='A'),'12345','12345','00000','N','none','none' FROM dual WHERE ((SELECT COUNT(*) FROM users WHERE userip='192.168.0.1' AND type='A' AND daysleft = 0) = 0);

The interesting part is this:
(SELECT IFNULL(MIN(daysleft),30) from users WHERE userip='192.168.0.1' AND type='A')

If theres a record in the table for the user's IP, upon registrering for a account, it will take the smallest daysleft found, else it will give the user 30 days in daysleft.

This is good for example if you want to give 30 days trial period, and still allow members in a household to register for their own accounts, but not allowing longer trial priod by registrering multiple own accounts.

In this case, if a household has a user with lets say 10 trial days left, and a another user in the household registers himself for a account, that user will too get 10 trial days left.
If theres no accounts on a specific household, the user will get a full 30 days trial period.
  Posted by Joseph Edmonds on January 19, 2012
Note using the case syntax you can update many rows with one query. This can have a really dramatic postitive impact on performance if you have a large number of updates to do.

For a nice PHP function to handle this see here:
http://www.edmondscommerce.co.uk/mysql/compare-two-columns-in-mysql/

  Posted by Mike Jorgenstam on February 28, 2014
This does not work to validate that all actually fall within as some can have > 1 five while still being within 20 sum and then discards second statement after OR

Thus, MySQL reads the passed if clause in the statement from LEFT TO RIGHT and not from RIGHT TO LEFT as some say...

-- This fails
IF ((@r7q0+@r7q1+@r7q2+@r7q3+@r7q4+@r7q5) < 20) OR
OR (@r7q5 > 1) THEN
SET @res = 0;
END IF;

-- This works
IF ((@r7q6+@r7q7+@r7q8+@r7q9+@r7q10) > 0) OR (@r7q5 > 1) THEN
SET @res = 0;
END IF;

-- This would work in some cases then
IF (@r7q5 > 1) OR
((@r7q0+@r7q1+@r7q2+@r7q3+@r7q4+@r7q5) < 20) THEN
SET @res = 0;
END IF;

Sign Up Login You must be logged in to post a comment.