Skip to content

Commit ba26800

Browse files
committed
New docs on expressions and constants
1 parent 81c9781 commit ba26800

File tree

4 files changed

+739
-6
lines changed

4 files changed

+739
-6
lines changed

decimal.md

Lines changed: 3 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -30,7 +30,8 @@ When inserting a decimal value:
3030

3131
When inserting into a `DECIMAL` column, format the value as a numeric literal, e.g., `1.2345` or `1`.
3232

33-
Alternately, you can cast a float as a decimal: `CAST(1.2345 AS DECIMAL)`. However, note that the precision will be limited to 17 digits in total (both to the left and right of the decimal point).
33+
For more details about decimal numeric formats,
34+
see the section on [SQL constants](sql-constants.html)
3435

3536
## Size
3637

@@ -83,4 +84,4 @@ Type | Details
8384

8485
## See Also
8586

86-
[Data Types](data-types.html)
87+
[Data Types](data-types.html)

float.md

Lines changed: 12 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -6,6 +6,9 @@ toc: false
66

77
The `FLOAT` [data type](data-types.html) stores inexact, floating-point numbers with up to 17 digits in total and at least one digit to the right of the decimal point.
88

9+
They are handled internally using the [standard double-precision
10+
(64-bit binary-encoded) IEEE754 format](https://en.wikipedia.org/wiki/IEEE_floating_point).
11+
912
<div id="toc"></div>
1013

1114
## Aliases
@@ -19,10 +22,15 @@ In CockroachDB, the following are aliases for `FLOAT`:
1922

2023
When inserting into a `FLOAT` column, format the value as a numeric literal, e.g., `1.2345` or `1`.
2124

22-
Alternately, you can cast `+Inf` (positive infinity), `-Inf` (negative infinity), or `NaN` (not a number) as a float:
25+
For more details about `FLOAT` numeric formats,
26+
see the section on [SQL constants](sql-constants.html).
27+
28+
The special IEEE754 values for positive infinity, negative infinity
29+
and Not A Number (NaN) cannot be entered using numeric literals directly and
30+
must be converted using an interpreted literal instead. For example:
2331

24-
- `CAST('+Inf' AS FLOAT)`
25-
- `CAST('-Inf' AS FLOAT)`
32+
- `FLOAT '+Inf'`
33+
- `'-Inf':::FLOAT`
2634
- `CAST('NaN' AS FLOAT)`
2735

2836
## Size
@@ -73,4 +81,4 @@ Type | Details
7381

7482
## See Also
7583

76-
[Data Types](data-types.html)
84+
[Data Types](data-types.html)

sql-constants.md

Lines changed: 220 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,220 @@
1+
---
2+
title: SQL Constant values
3+
summary: SQL Constants represent a simple value that doesn't change.
4+
toc: false
5+
---
6+
7+
SQL Constants represent a simple value that doesn't change.
8+
9+
<div id="toc"></div>
10+
11+
## Introduction
12+
13+
There are five categories of constants in CockroachDB:
14+
15+
- string literals: these define string values but their actual data type will
16+
be inferred from context, for example `'hello'`;
17+
- numeric literals: these define numeric values but their actual data
18+
type will be inferred from context, for example `-12.3`;
19+
- byte array literals: these define byte array values with data type
20+
`BYTES`, for example `b'hello'`;
21+
- interpreted literals: these define arbitrary values with an explicit
22+
type, for example `INTERVAL '3 days'`.
23+
- named constants: these have predefined values with a predefined
24+
type, for example `TRUE` or `NULL`.
25+
26+
## String literals
27+
28+
CockroachDB supports multiple formats for string literals:
29+
30+
- standard SQL string literals
31+
- string literals with C escape sequences
32+
- hexadecimal-encoded strings
33+
34+
The first two formats also allow arbitrary Unicode characters encoded as UTF-8.
35+
36+
In all these cases, the actual data type of a string literal is determined
37+
using the context where it appears.
38+
39+
For example:
40+
41+
| Expression | Data type of the string literal |
42+
|------------|---------------------------------|
43+
| `length('hello')` | `STRING` |
44+
| `now() + '3 day'` | `INTERVAL` |
45+
| `INSERT INTO tb(date_col) VALUES ('2013-01-02')` | `DATE` |
46+
47+
In general, the data type of a string literal is that demanded by the
48+
context if there is no ambiguity, or `STRING` otherwise.
49+
50+
Check our blog for
51+
[more information about the typing of string literals](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/).
52+
53+
### Standard SQL string literals
54+
55+
SQL string literals are formed by an arbitrary sequence of characters
56+
enclosed between single quotes (`'`), for example `'hello world'`.
57+
to include a single quote in the string, use a double single quote.
58+
59+
For example:
60+
61+
```sql
62+
SELECT 'hello' as a, 'it''s a beautiful day' as b;
63+
+-------+----------------------+
64+
| a | b |
65+
+-------+----------------------+
66+
| hello | it's a beautiful day |
67+
+-------+----------------------+
68+
```
69+
70+
For compatibility with the SQL standard, CockroachDB also recognizes
71+
the following special syntax: two simple string literals separated by
72+
a newline character are automatically concatenated together to form a
73+
single constant. For example:
74+
75+
```sql
76+
SELECT 'hello'
77+
' world!' as a;
78+
+--------------+
79+
| a |
80+
+--------------+
81+
| hello world! |
82+
+--------------+
83+
```
84+
85+
(This special syntax only works if the two simple literals are
86+
separated by a newline character. For example `'hello' ' world!'`
87+
doesn't work. This is mandated by the SQL standard.)
88+
89+
### String literals with character escapes
90+
91+
CockroachDB also supports string literals containing escape sequences
92+
like in the programming language C. These are constructed by prefixing
93+
the string literal with the letter `e`, for example
94+
`e'hello\nworld!'`.
95+
96+
The following escape sequences are supported:
97+
98+
Escape Sequence | Interpretation
99+
----------------|---------------
100+
`\a` | ASCII code 7 (BEL)
101+
`\b` | backspace (ASCII 8)
102+
`\t` | tab (ASCII 9)
103+
`\n` | newline (ASCII 10)
104+
`\v` | vertical tab (ASCII 11)
105+
`\f` | form feed (ASCII 12)
106+
`\r` | carriage return (ASCII 13)
107+
`\xHH` | hexadecimal byte value
108+
`\ooo` | octal byte value
109+
`\uXXXX` | 16-bit hexadecimal Unicode character value
110+
`\UXXXXXXXX` | 32-bit hexadecimal Unicode character value
111+
112+
For example, the `e'x61\141\u0061'` escape string represents the
113+
hexadecimal byte, octal byte, and 16-bit hexadecimal Unicode character
114+
values equivalent to the `'aaa'` string literal.
115+
116+
### Hexadecimal-encoded string literals
117+
118+
This is a CockroachDB-specific extension to express string literals: the
119+
delimiter `x'` followed by an arbitrary sequence of hexadecimal
120+
digits, followed by a closing `'`.
121+
122+
For example, `x'636174'` or `X'636174'` are equivalent to `'cat'`.
123+
124+
## Numeric literals
125+
126+
Numeric literals can have the following forms:
127+
128+
```
129+
[+-]9999
130+
[+-]9999.[9999][e[+-]999]
131+
[+-][9999].9999[e[+-]999]
132+
[+-]9999e[+-]999
133+
134+
[+-]0xAAAA
135+
```
136+
137+
Some examples:
138+
139+
```
140+
+4269
141+
3.1415
142+
-.001
143+
6.626e-34
144+
50e6
145+
0xcafe111
146+
```
147+
148+
The actual data type of a numeric constant depends both on the context
149+
where it is used, its literal format and its numeric value.
150+
151+
| Syntax | Possible data types |
152+
|--------|---------------------|
153+
| Contains a decimal separator | `FLOAT`, `DECIMAL` |
154+
| Contains an exponent | `FLOAT`, `DECIMAL` |
155+
| Contains a value larger than 2^64 in magnitude | `FLOAT`, `DECIMAL` |
156+
| Otherwise | `INT`, `DECIMAL`, `FLOAT` |
157+
158+
Of the possible data types, which one is actually used is then further
159+
refined depending on context.
160+
161+
Check our blog for
162+
[more information about the typing of numeric literals](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/).
163+
164+
## Byte array literals
165+
166+
A byte array literal uses the same syntax as string literals containing character escapes,
167+
using a `b` prefix instead of `e`. Any character escapes are interpreted like they
168+
would be for string literals.
169+
170+
For example: `b'hello,\x32world'`
171+
172+
The two differences between byte array literals and string literals with character escapes are:
173+
174+
- byte array literals always have data type `BYTES`, whereas the data
175+
type of a string literal depends on context;
176+
- byte array literals may contain invalid UTF-8 byte sequences,
177+
whereas string literals must always contain valid UTF-8 sequences.
178+
179+
## Interpreted literals
180+
181+
A constant of any data type can be formed using either of the following formats:
182+
183+
```
184+
type 'string'
185+
'string':::type
186+
```
187+
188+
The value of the string part is used as input for the conversion function to the
189+
specified data type, and the result is used as a constant with that data type.
190+
191+
Examples:
192+
193+
```
194+
DATE '2013-12-23'
195+
BOOL 'FALSE'
196+
'42.69':::INT
197+
'TRUE':::BOOL
198+
'3 days':::INTERVAL
199+
```
200+
201+
Additionally, for compatibility with PostgreSQL, the notation
202+
`'string'::type` and `CAST('string' AS type)` is also recognized as an
203+
interpreted literal. These are special cases of
204+
[cast expressions](sql-expressions.html).
205+
206+
## Named constants
207+
208+
CockroachDB recognizes the following SQL named constants:
209+
210+
- `TRUE` and `FALSE`, the two possible values of data type `BOOL`;
211+
- `NULL`, the special SQL symbol that indicates "no value present".
212+
213+
Note that `NULL` is a valid constant for any type: its actual data
214+
type during expression evaluation is determined based on context.
215+
216+
## See Also
217+
218+
- [Expressions](sql-expressions.html)
219+
- [Data Types](data-types.html)
220+

0 commit comments

Comments
 (0)