Skip to content

Latest commit

 

History

History
250 lines (179 loc) · 8.98 KB

literal-values.md

File metadata and controls

250 lines (179 loc) · 8.98 KB
title summary aliases
Literal Values
This article introduces the literal values ​​of TiDB SQL statements.
/docs/dev/literal-values/
/docs/dev/reference/sql/language-structure/literal-values/

Literal Values

TiDB literal values include character literals, numeric literals, time and date literals, hexadecimal, binary literals, and NULL literals. This document introduces each of these literal values.

This document describes String literals, Numeric literals, NULL values, Hexadecimal literals, Date and time literals, Boolean literals, and Bit-value literals.

String literals

A string is a sequence of bytes or characters, enclosed within either single quote ' or double quote " characters. For example:

'example string'
"example string"

Quoted strings placed next to each other are concatenated to a single string. The following lines are equivalent:

'a string'
'a' ' ' 'string'
"a" ' ' "string"

If the ANSI_QUOTES SQL MODE is enabled, string literals can be quoted only within single quotation marks because a string quoted within double quotation marks is interpreted as an identifier.

The string is divided into the following two types:

  • Binary string: It consists of a sequence of bytes, whose charset and collation are both binary, and uses byte as the unit when compared with each other.
  • Non-binary string: It consists of a sequence of characters and has various charsets and collations other than binary. When compared with each other, non-binary strings use characters as the unit. A charater might contian multiple bytes, depending on the charset.

A string literal may have an optional character set introducer and COLLATE clause, to designate it as a string that uses a specific character set and collation.

[_charset_name]'string' [COLLATE collation_name]

For example:

SELECT _latin1'string';
SELECT _binary'string';
SELECT _utf8'string' COLLATE utf8_bin;

You can use N'literal' (or n'literal') to create a string in the national character set. The following statements are equivalent:

SELECT N'some text';
SELECT n'some text';
SELECT _utf8'some text';

To represent some special characters in a string, you can use escape characters to escape:

Escape Characters Meaning
\0 An ASCII NUL (X'00') character
\' A single quote ' character
\" A double quote " character
\b A backspace character
\n A line break (newline) character
\r A carriage return character
\t A tab character
\z ASCII 26 (Ctrl + Z)
\\ A backslash \ character
\% A % character
\_ A _ character

If you want to represent " in the string surrounded by ', or ' in the string surrounded by ", you do not need to use escape characters.

For more information, see String Literals in MySQL.

Numeric literals

Numeric literals include integer and DECIMAL literals and floating-point literals.

Integer may include . as a decimal separator. Numbers may be preceded by - or + to indicate a negative or positive value respectively.

Exact-value numeric literals can be represented as 1, .2, 3.4, -5, -6.78, +9.10.

Numeric literals can also be represented in scientific notation, such as 1.2E3, 1.2E-3, -1.2E3, -1.2E-3.

For more information, see Numeric Literals in MySQL.

Date and time literals

Date and time literal values can be represented in several formats, such as quoted strings or as numbers. When TiDB expects a date, it interprets any of '2017-08-24', '20170824' and 20170824 as a date.

TiDB supports the following date formats:

  • 'YYYY-MM-DD' or 'YY-MM-DD': The - delimiter here is not strict. It can be any punctuation. For example, '2017-08-24', '2017&08&24', '2012@12^31' are all valid date formats. The only special punctuation is '.', which is is treated as a decimal point to separate the integer and fractional parts. Date and time can be separated by T or a white space. For example, 2017-8-24 10:42:00 and 2017-8-24T10:42:00 represents the same date and time.
  • 'YYYYMMDDHHMMSS' or 'YYMMDDHHMMSS': For example, '20170824104520' and '170824104520' are regarded as '2017-08-24 10:45:20'. However, if you provide a value out of range, such as '170824304520', it is not treated as a valid date.
  • YYYYMMDDHHMMSS or YYMMDDHHMMSS: Note that these formats have no single or double quotes, but a number. For example, 20170824104520 is interpreted as '2017-08-24 10:45:20'.

DATETIME or TIMESTAMP values can be followed by a fractional part, used to represent microseconds precision (6 digits). The fractional part should always be separated from the rest of the time by a decimal point ..

The year value containing only two digits is ambiguous. It is recommended to use the four-digit year format. TiDB interpretes the two-digit year value according to the following rules:

  • If the year value is in the range of 70-99, it is converted to 1970-1999.
  • If the year value is in the range of 00-69, it is converted to 2000-2069.

For month or day values ​​less than 10, '2017-8-4' is the same as '2017-08-04'. The same is true for Time. For example, '2017-08-24 1:2:3' is the same as '2017-08-24 01:02:03'.

When the date or time value is required, TiDB selects the specified format according to the length of the value:

  • 6 digits: YYMMDD.
  • 12 digits: YYMMDDHHMMSS.
  • 8 digits: YYYYMMDD.
  • 14 digits: YYYYMMDDHHMMSS.

TiDB supports the following formats for time values:

  • 'D HH:MM:SS', or 'HH:MM:SS', 'HH:MM', 'D HH:MM', 'D HH', 'SS': D means days and the valid value range is 0-34.
  • A number in HHMMSS format: For example, 231010 is interpreted as '23:10:10'.
  • A number in any of SS, MMSS, and HHMMSSformats can be regarded as time.

The decimal point of the Time type is also ., with a precision of up to 6 digits after the decimal point.

See MySQL date and time literals for more details.

Boolean Literals

The constants TRUE and FALSE are equal to 1 and 0 respectively, which are not case sensitive.

{{< copyable "sql" >}}

SELECT TRUE, true, tRuE, FALSE, FaLsE, false;
+------+------+------+-------+-------+-------+
| TRUE | true | tRuE | FALSE | FaLsE | false |
+------+------+------+-------+-------+-------+
|    1 |    1 |    1 |     0 |     0 |     0 |
+------+------+------+-------+-------+-------+
1 row in set (0.00 sec)

Hexadecimal literals

Hexadecimal literal values are written using X'val' or 0xval notation, where val contains hexadecimal digits. A leading 0x is case sensitive and cannot be written as 0X.

Legal hexadecimal literals:

X'ac12'
X'12AC'
x'ac12'
x'12AC'
0xac12
0x12AC

Illegal hexadecimal literals:

X'1z' (z is not a hexadecimal legal digit)
0X12AC (0X must be written as 0x)

Hexadecimal literals written using X'val' notation must contain an even number of digits. To avoid the syntax error, pad the value with a leading zero:

mysql> select X'aff';
ERROR 1105 (HY000): line 0 column 13 near ""hex literal: invalid hexadecimal format, must even numbers, but 3 (total length 13)
mysql> select X'0aff';
+---------+
| X'0aff' |
+---------+
| 0x0aff  |
+---------+
1 row in set (0.00 sec)

By default, a hexadecimal literal is a binary string.

To convert a string or a number to a string in hexadecimal format, use the HEX() function:

mysql> SELECT HEX('TiDB');
+-------------+
| HEX('TiDB') |
+-------------+
| 54694442    |
+-------------+
1 row in set (0.01 sec)

mysql> SELECT X'54694442';
+-------------+
| X'54694442' |
+-------------+
| TiDB        |
+-------------+
1 row in set (0.00 sec)

Bit-value literals

Bit-value literals are written using b'val' or 0bval notation. The val is a binary value written using zeros and ones. A leading 0b is case sensitive and cannot be written as 0B.

Legal bit-value literals:

b'01'
B'01'
0b01

Illegal bit-value literals:

b'2' (2 is not a binary digit; it must be 0 or 1)
0B01 (0B must be written as 0b)

By default, a bit-value literal is a binary string.

Bit values are returned as binary values, which may not display well in the MySQL client. To convert a bit value to printable form, you can use a conversion function such as BIN() or HEX().

CREATE TABLE t (b BIT(8));
INSERT INTO t SET b = b'00010011';
INSERT INTO t SET b = b'1110';
INSERT INTO t SET b = b'100101';

mysql> SELECT b+0, BIN(b), HEX(b) FROM t;
+------+--------+--------+
| b+0  | BIN(b) | HEX(b) |
+------+--------+--------+
|   19 | 10011  | 13     |
|   14 | 1110   | E      |
|   37 | 100101 | 25     |
+------+--------+--------+
3 rows in set (0.00 sec)

NULL Values

NULL means the data is empty, which is case-insensitive, and is synonymous with \N (case-sensitive).

Note:

NULL is not the same as 0, nor the empty string ''.