Documentation Home
MySQL 5.5 Reference Manual
Related Documentation Download this Manual
PDF (US Ltr) - 27.2Mb
PDF (A4) - 27.2Mb
PDF (RPM) - 25.8Mb
HTML Download (TGZ) - 6.5Mb
HTML Download (Zip) - 6.6Mb
HTML Download (RPM) - 5.6Mb
Man Pages (TGZ) - 158.5Kb
Man Pages (Zip) - 262.1Kb
Info (Gzip) - 2.6Mb
Info (Zip) - 2.6Mb
Excerpts from this Manual

MySQL 5.5 Reference Manual  /  Functions and Operators  /  Bit Functions and Operators

12.12 Bit Functions and Operators

Table 12.16 Bit Functions and Operators

Name Description
BIT_COUNT() Return the number of bits that are set
& Bitwise AND
~ Bitwise inversion
| Bitwise OR
^ Bitwise XOR
<< Left shift
>> Right shift

Bit functions and operators comprise BIT_COUNT(), BIT_AND(), BIT_OR(), BIT_XOR(), &, |, ^, ~, <<, and >>. (BIT_AND(), BIT_OR(), and BIT_XOR() are aggregate functions described at Section 12.17.1, “Aggregate (GROUP BY) Function Descriptions”.) Bit functions and operators require BIGINT (64-bit integer) arguments and return BIGINT values, so they have a maximum range of 64 bits. Arguments of other types (such as the BINARY and VARBINARY binary string types) are converted to BIGINT and truncation might occur.

The following list describes available bit functions and operators:

  • |

    Bitwise OR.

    The result is an unsigned 64-bit integer.

    mysql> SELECT 29 | 15;
            -> 31
  • &

    Bitwise AND.

    The result is an unsigned 64-bit integer.

    mysql> SELECT 29 & 15;
            -> 13
  • ^

    Bitwise XOR.

    The result is an unsigned 64-bit integer.

    mysql> SELECT 1 ^ 1;
            -> 0
    mysql> SELECT 1 ^ 0;
            -> 1
    mysql> SELECT 11 ^ 3;
            -> 8
  • <<

    Shifts a longlong (BIGINT) number to the left.

    The result is an unsigned 64-bit integer. The value is truncated to 64 bits. In particular, if the shift count is greater or equal to the width of an unsigned 64-bit number, the result is zero.

    mysql> SELECT 1 << 2;
            -> 4
  • >>

    Shifts a longlong (BIGINT) number to the right.

    The result is an unsigned 64-bit integer. The value is truncated to 64 bits. In particular, if the shift count is greater or equal to the width of an unsigned 64-bit number, the result is zero.

    mysql> SELECT 4 >> 2;
            -> 1
  • ~

    Invert all bits.

    The result is an unsigned 64-bit integer.

    mysql> SELECT 5 & ~1;
            -> 4
  • BIT_COUNT(N)

    Returns the number of bits that are set in the argument N as an unsigned 64-bit integer, or NULL if the argument is NULL.

    mysql> SELECT BIT_COUNT(29), BIT_COUNT(b'101010');
            -> 4, 3

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 Chris Wagner on May 28, 2011
@Mark Cain.

What u just described is a reroll of FIND_IN_SET and ENUM.

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