diff --git a/bool.md b/bool.md index a10768c521a..d212bbc0982 100644 --- a/bool.md +++ b/bool.md @@ -12,14 +12,17 @@ The `BOOL` [data type](data-types.html) stores a Boolean value of `false` or `tr In CockroachDB, `BOOLEAN` is an alias for `BOOL`. -## Format +## Syntax -When inserting into a `BOOL` column, format the value as `false` or `true` (case-insensitive). +There are two predefined +[named constants](sql-constants.html#named-constants) for `BOOL`: +`TRUE` and `FALSE` (the names are case-insensitive). -Alternately, you can cast `0` or `1` as a `BOOL`: +Alternately, a boolean value can be obtained by coercing a numeric +value: zero is coerced to `FALSE`, and any non-zero value to `TRUE`. - `CAST(0 AS BOOL)` (false) -- `CAST(1 AS BOOL)` (true) +- `CAST(123 AS BOOL)` (true) ## Size @@ -69,4 +72,4 @@ Type | Details ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/bytes.md b/bytes.md index 6aa1435f4d7..a0fa3e2a8ea 100644 --- a/bytes.md +++ b/bytes.md @@ -15,15 +15,17 @@ In CockroachDB, the following are aliases for `BYTES`: - `BYTEA` - `BLOB` -## Formats +## Syntax -When inserting into a `BYTES` column, use any of the following formats: +To express a byte array constant, see the section on +[byte array literals](sql-constants.html#byte-array-literals) for more +details. For example, the following three are equivalent literals for the same +byte array: `b'abc'`, `b'\141\142\143'`, `b'\x61\x62\x63'`. -- 1 octet per byte: `b'\141\061\142\062\143\063'` -- 2 hexadecimal digits per byte: `b'\x61\x31\x62\x32\x63\x33'`. -- String literal: `'a1b2c3'` - -You can also use these in combination, for example, `b'\141\061\x62\x32\c3'`. +In addition to this syntax, CockroachDB also supports using +[string literals](sql-constants.html#string-literals), including the +syntax `'...'`, `e'...'` and `x'....'` in contexts where a byte array +is otherwise expected. ## Size @@ -34,7 +36,12 @@ The size of a `BYTES` value is variable, but it's recommended to keep values und ~~~ sql > CREATE TABLE bytes (a INT PRIMARY KEY, b BYTES); -> INSERT INTO bytes VALUES (1, 'abc'), (2, b'\141\142\143'), (3, b'\x61\x62\x63'), (4, b'\141\x62\c'); +> -- explicitly typed BYTES literals +> INSERT INTO bytes VALUES (1, b'\141\142\143'), (2, b'\x61\x62\x63'), (3, b'\141\x62\c'); + +> -- string literal implicitly typed as BYTES +> INSERT INTO bytes VALUES (4, 'abc'); + > SELECT * FROM bytes; ~~~ @@ -50,14 +57,16 @@ The size of a `BYTES` value is variable, but it's recommended to keep values und (4 rows) ~~~ -## Supported Casting & Conversion +## Supported Conversions -`BYTES` values can be [cast](data-types.html#data-type-conversions--casts) to any of the following data types: +`BYTES` values can be +[cast](data-types.html#data-type-conversions--casts) explicitly to +`STRING`. The conversion verifies that the byte array contains only +valid UTF-8 byte sequences; an error is reported otherwise. -Type | Details ------|-------- -`STRING` | Requires the byte array to contain only valid UTF-8 character encodings. +`STRING` values can be cast explicitly to `BYTES`. This conversion +always succeeds. ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/data-types.md b/data-types.md index 47a31258089..9b154bcd552 100644 --- a/data-types.md +++ b/data-types.md @@ -26,12 +26,20 @@ Type | Description | Example CockroachDB supports explicit type conversions using the following methods: -- `::`, or its equivalent longer form `CAST( AS )`, which converts an arbitrary expression of one built-in type to another (this is also known as "casting"). For example: -`NOW()::DECIMAL`, `VARIANCE(a+2)::INT`. - - ` 'string literal'`, to convert from the literal representation of a value to a value of that type. For example: -`DATE '2008-12-21'`, `INT '123'`, or `BOOL 'true'`. + `DATE '2008-12-21'`, `INT '123'`, or `BOOL 'true'`. + +- `::`, or its equivalent longer form `CAST( AS )`, which converts an arbitrary expression of one built-in type to another (this is also known as type coercion or "casting"). For example: + `NOW()::DECIMAL`, `VARIANCE(a+2)::INT`. + + {{site.data.alerts.callout_success}} + To create constant values, consider using a + type annotation + instead of a cast, as it provides more predictable results. + {{site.data.alerts.end}} - Other [built-in conversion functions](functions-and-operators.html) when the type is not a SQL type, for example `from_ip()`, `to_ip()` to convert IP addresses between `STRING` and `BYTES` values. -You can find each data type's supported converstion and casting on its respective page in the **Supported Casting & Conversion** section. + +You can find each data type's supported converstion and casting on its +respective page in its section **Supported Casting & Conversion**. diff --git a/date.md b/date.md index e0c8765d748..0cdf979d231 100644 --- a/date.md +++ b/date.md @@ -8,13 +8,21 @@ The `DATE` [data type](data-types.html) stores a year, month, and day.
-## Format +## Syntax -When inserting into a `DATE` column, format the value as `DATE '2016-01-25'`. +A constant value of type `DATE` can be expressed using an +[interpreted literal](sql-constants.html#interpreted-literals), or a +string literal +[annotated with](sql-expressions.html#explicitly-typed-expressions) +type `DATE` or +[coerced to](sql-expressions.html#explicit-type-coercions) type +`DATE`. -Alternatively, you can use a string literal, e.g., `'2016-01-25'`, which CockroachDB will resolve into the `DATE` type. +The string format for dates is `YYYY-MM-DD`. For example: `DATE '2016-12-23'`. -Note that in some contexts, dates may be displayed with hours, minutes, seconds, and timezone set to 0. +CockroachDB also supports using uninterpreted +[string literals](sql-constants.html#string-literals) in contexts +where a `DATE` value is otherwise expected. ## Size @@ -36,8 +44,12 @@ A `DATE` column supports values up to 8 bytes in width, but the total storage si +-------+------+-------+---------+ ~~~ ~~~ sql +> -- explicitly typed DATE literal > INSERT INTO dates VALUES (DATE '2016-03-26', 12345); +> -- string literal implicitly typed as DATE +> INSERT INTO dates VALUES ('2016-03-27', 12345); + > SELECT * FROM dates; ~~~ ~~~ @@ -45,6 +57,7 @@ A `DATE` column supports values up to 8 bytes in width, but the total storage si | a | b | +---------------------------+-------+ | 2016-03-26 00:00:00+00:00 | 12345 | +| 2016-03-27 00:00:00+00:00 | 12345 | +---------------------------+-------+ ~~~ @@ -64,4 +77,4 @@ Type | Details ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/decimal.md b/decimal.md index 0a45b136712..f14b0f4e72b 100644 --- a/decimal.md +++ b/decimal.md @@ -26,11 +26,10 @@ When inserting a decimal value: - If digits to the left and right of the decimal point exceed the column's `precision`, CockroachDB gives an error. - If the column's `precision` and `scale` are identical, the inserted value must round to less than 1. -## Format +## Syntax -When inserting into a `DECIMAL` column, format the value as a numeric literal, e.g., `1.2345` or `1`. - -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). +A constant value of type `DECIMAL` can be entered as a [numeric literal](sql-constants.html#numeric-literals). +For example: `1.414` or `-1234`. ## Size @@ -53,19 +52,19 @@ The size of a `DECIMAL` value is variable, starting at 9 bytes. It's recommended +-------+---------------+-------+---------+ ~~~ ~~~ sql -> INSERT INTO decimals VALUES (1.01234567890123456789, 1.01234567890123456789, CAST(1.01234567890123456789 AS DECIMAL)); +> INSERT INTO decimals VALUES (1.01234567890123456789, 1.01234567890123456789, 1.01234567890123456789); > SELECT * FROM decimals; ~~~ ~~~ -+------------------------+---------+--------------------+ -| a | b | c | -+------------------------+---------+--------------------+ -| 1.01234567890123456789 | 1.01235 | 1.0123456789012346 | -+------------------------+---------+--------------------+ ++------------------------+---------+-----------------------+ +| a | b | c | ++------------------------+---------+-----------------------+ +| 1.01234567890123456789 | 1.01235 | 1.0123456789012346789 | ++------------------------+---------+-----------------------+ # The value in "a" matches what was inserted exactly. # The value in "b" has been rounded to the column's scale. -# The value in "c" has been limited to 17 digits. +# The value in "c" is handled like "a" because NUMERIC is an alias. ~~~ ## Supported Casting & Conversion @@ -79,8 +78,6 @@ Type | Details `BOOL` | **0** converts to `false`; all other values convert to `true` `STRING` | –– -{{site.data.alerts.callout_info}}Because the SERIAL data type represents values automatically generated CockroachDB to uniquely identify rows, you cannot meaningfully cast other data types as SERIAL values.{{site.data.alerts.end}} - ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/float.md b/float.md index 4db83c9a00b..a1248668592 100644 --- a/float.md +++ b/float.md @@ -4,7 +4,10 @@ summary: The FLOAT data type stores inexact, floating-point numbers with up to 1 toc: false --- -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. +The `FLOAT` [data type](data-types.html) stores inexact, floating-point numbers with up to 17 digits of decimal precision. + +They are handled internally using the [standard double-precision +(64-bit binary-encoded) IEEE754 format](https://en.wikipedia.org/wiki/IEEE_floating_point).
@@ -15,14 +18,20 @@ In CockroachDB, the following are aliases for `FLOAT`: - `REAL` - `DOUBLE PRECISION` -## Format +## Syntax -When inserting into a `FLOAT` column, format the value as a numeric literal, e.g., `1.2345` or `1`. +A constant value of type `FLOAT` can be entered as a [numeric literal](sql-constants.html#numeric-literals). +For example: `1.414` or `-1234`. -Alternately, you can cast `+Inf` (positive infinity), `-Inf` (negative infinity), or `NaN` (not a number) as a float: +The special IEEE754 values for positive infinity, negative infinity +and Not A Number (NaN) cannot be entered using numeric literals +directly and must be converted using an +[interpreted literal](sql-constants.html#interpreted-literals) or an +[explicit conversion](sql-expressions.html#explicit-type-coercions) from +a string literal instead. For example: -- `CAST('+Inf' AS FLOAT)` -- `CAST('-Inf' AS FLOAT)` +- `FLOAT '+Inf'` +- `'-Inf'::FLOAT` - `CAST('NaN' AS FLOAT)` ## Size @@ -61,16 +70,15 @@ A `FLOAT` column supports values up to 8 bytes in width, but the total storage s ## Supported Casting & Conversion -`DECIMAL` values can be [cast](data-types.html#data-type-conversions--casts) to any of the following data types: +`FLOAT` values can be [cast](data-types.html#data-type-conversions--casts) to any of the following data types: Type | Details -----|-------- `INT` | Truncates decimal precision and requires values to be between -2^63 and 2^63-1 -`DECIMAL` | –– +`DECIMAL` | Causes an error to be reported if the value is NaN or +/- Inf. `BOOL` | **0** converts to `false`; all other values convert to `true` - -{{site.data.alerts.callout_info}}Because the SERIAL data type represents values automatically generated CockroachDB to uniquely identify rows, you cannot meaningfully cast other data types as SERIAL values.{{site.data.alerts.end}} +`STRING` | -- ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/int.md b/int.md index 833227f64d3..f0ef6b5701f 100644 --- a/int.md +++ b/int.md @@ -20,17 +20,10 @@ In CockroachDB, the following are aliases for `INT`: - `INT64` - `BIGINT` -## Formats +## Syntax -An `INT` column accepts numeric literals and hexadecimal-encoded numeric literals. - -### Numeric Literal - -When inserting a numeric literal into an `INT` column, format the value as `12345`. - -### Hexadecimal-Encoded Numeric Literal - -When inserting a hexadecimal-encoded numeric literal into a `INT` column, format the value as hexadecimal digits preceded by `0x`. For example, `0xcafe1111` corresponds to the numeric literal `3405648145`. +A constant value of type `INT` can be entered as a [numeric literal](sql-constants.html#numeric-literals). +For example: `42`, `-1234` or `0xCAFE`. ## Size @@ -74,15 +67,13 @@ CockroachDB does not offer multiple integer types for different widths; instead, Type | Details -----|-------- `DECIMAL` | –– -`FLOAT` | Requires `INT` value to be less than 2^53 +`FLOAT` | Loses precision if the `INT` value is larger than 2^53 in magnitude `BOOL` | **0** converts to `false`; all other values convert to `true` `DATE` | Converts to days since the Unix epoch (Jan. 1, 1970) `TIMESTAMP` | Converts to seconds since the Unix epoch (Jan. 1, 1970) `INTERVAL` | Converts to microseconds `STRING` | –– -{{site.data.alerts.callout_info}}Because the SERIAL data type represents values automatically generated CockroachDB to uniquely identify rows, you cannot meaningfully cast other data types as SERIAL values.{{site.data.alerts.end}} - ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/interval.md b/interval.md index 39eab37aca5..82fd3bcff60 100644 --- a/interval.md +++ b/interval.md @@ -8,18 +8,28 @@ The `INTERVAL` [data type](data-types.html) stores a value that represents a spa
-## Formats +## Syntax -When inserting into an `INTERVAL` column, use one of the following formats: +A constant value of type `INTERVAL` can be expressed using an +[interpreted literal](sql-constants.html#interpreted-literals), or a +string literal +[annotated with](sql-expressions.html#explicitly-typed-expressions) +type `INTERVAL` or +[coerced to](sql-expressions.html#explicit-type-coercions) type +`INTERVAL`. + +`INTERVAL` constants can be expressed using the following formats: Format | Description -------|-------- -Golang | `INTERVAL '1h2m3s4ms5us6ns'`

Note that `ms` is milliseconds, `us` is microseconds, and `ns` is nanoseconds. Also, all fields support both integers and floats. -Traditional Postgres | `INTERVAL '1 year 2 months 3 days 4 hours 5 minutes 6 seconds'` -ISO 8601 | `INTERVAL 'P1Y2M3DT4H5M6S'` SQL Standard | `INTERVAL 'Y-M D H:M:S'`

`Y-M D`: Using a single value defines days only; using two values defines years and months. Values must be integers.

`H:M:S`: Using a single value defines seconds only; using two values defines hours and minutes. Values can be integers or floats.

Note that each side is optional. +ISO 8601 | `INTERVAL 'P1Y2M3DT4H5M6S'` +Traditional PostgreSQL | `INTERVAL '1 year 2 months 3 days 4 hours 5 minutes 6 seconds'` +Golang | `INTERVAL '1h2m3s4ms5us6ns'`

Note that `ms` is milliseconds, `us` is microseconds, and `ns` is nanoseconds. Also, all fields support both integers and floats. -Alternatively, you can use a string literal, e.g., `'1h2m3s4ms5us6ns'` or`'1 year 2 months 3 days 4 hours 5 minutes 6 seconds'`, which CockroachDB will resolve into the `INTERVAL` type. +CockroachDB also supports using uninterpreted +[string literals](sql-constants.html#string-literals) in contexts +where a `INTERVAL` value is otherwise expected. Intervals are stored internally as months, days, and nanoseconds. @@ -51,9 +61,9 @@ CREATE TABLE ~~~ ~~~ sql -> INSERT INTO intervals VALUES - (1, INTERVAL '1h2m3s4ms5us6ns'), - (2, INTERVAL '1 year 2 months 3 days 4 hours 5 minutes 6 seconds'), +> INSERT INTO intervals VALUES + (1, INTERVAL '1h2m3s4ms5us6ns'), + (2, INTERVAL '1 year 2 months 3 days 4 hours 5 minutes 6 seconds'), (3, INTERVAL '1-2 3 4:5:6'); ~~~ @@ -89,4 +99,4 @@ Type | Details ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/serial.md b/serial.md index 8d1c09ba57e..32aff54781c 100644 --- a/serial.md +++ b/serial.md @@ -4,9 +4,28 @@ summary: The SERIAL data type defaults to a unique 64-bit signed integer that is toc: false --- -The `SERIAL` [data type](data-types.html) defaults to a unique 64-bit signed integer. The default value is the combination of the insert timestamp and the ID of the node executing the insert. This combination is guaranteed to be globally unique. Also, because value generation does not require talking to other nodes, it is much faster than sequentially auto-incrementing a value, which requires distributed coordination. - -{{site.data.alerts.callout_info}}This data type is experimental. We believe it is a better solution than PostgeSQL's SERIAL and MySQL's AUTO_INCREMENT types, both of which auto-increment integers but not necessarily in a strictly sequential fashion (see the Auto-Incrementing Is Not Always Sequential example below). However, if you find that this feature is incompatible with your application, please open an issue or chat with us on Gitter.{{site.data.alerts.end}} +The `SERIAL` [data type](data-types.html) is a column data type which +generates new integer values on each default insert. The default value +is the combination of the insert timestamp and the ID of the node +executing the insert. This combination is guaranteed to be globally +unique. Also, because value generation does not require talking to +other nodes, it is much faster than sequentially auto-incrementing a +value, which requires distributed coordination. + +{{site.data.alerts.callout_info}} +This data type is experimental. We believe it is a better solution +than PostgeSQL's SERIAL and MySQL's AUTO_INCREMENT types, both of +which auto-increment integers but not necessarily in a strictly +sequential fashion (see the + +Auto-Incrementing Is Not Always Sequential + example below). However, if you find that this feature is incompatible +with your application, please +open an +issue or +chat +with us on Gitter. +{{site.data.alerts.end}}
@@ -19,13 +38,15 @@ In CockroachDB, the following are aliases for `SERIAL`: - `SMALLSERIAL` - `BIGSERIAL` -## Format +## Syntax -The `SERIAL` type is generally used to default to a unique ID. When inserting into a `SERIAL` column, you therefore do not manually specify a value. +Any `INT` value is a valid `SERIAL` value; in particular constant +`SERIAL` values can be expressed using +[numeric literals](sql-constants.html#numeric-literals). ## Size -A `SERIAL` column supports values up to 8 bytes in width, but the total storage size is likely to be larger due to CockroachDB metadata. +[Same as `INT`](int.html#size). ## Examples @@ -37,7 +58,7 @@ In this example, we create a table with the `SERIAL` column as the `PRIMARY KEY` > CREATE TABLE serial (a SERIAL PRIMARY KEY, b STRING(30), c BOOL); ~~~ -The [`SHOW COLUMNS`](show-columns.html) statement shows that the `SERIAL` type is just an alias for `INT` with `unique_rowid()` as the default. +The [`SHOW COLUMNS`](show-columns.html) statement shows that the `SERIAL` type is just an alias for `INT` with `unique_rowid()` as the default. ~~~ sql > SHOW COLUMNS FROM serial; @@ -52,10 +73,13 @@ The [`SHOW COLUMNS`](show-columns.html) statement shows that the `SERIAL` type i +-------+------------+-------+----------------+ ~~~ -When we insert 3 rows without values in column `a` and return the new rows, we see that each row has defaulted to a unique value in column `a`. +When we insert rows without values in column `a` and display the new +rows, we see that each row has defaulted to a unique value in column +`a`. ~~~ sql -> INSERT INTO serial (b,c) VALUES ('red', true), ('yellow', false), ('pink', true) RETURNING *; +> INSERT INTO serial (b,c) VALUES ('red', true), ('yellow', false), ('pink', true); +> INSERT INTO serial (a,b,c) VALUES (123, 'white', false); ~~~ ~~~ +--------------------+--------+-------+ @@ -64,29 +88,30 @@ When we insert 3 rows without values in column `a` and return the new rows, we s | 148656994422095873 | red | true | | 148656994422161409 | yellow | false | | 148656994422194177 | pink | true | +| 123 | white | false | +--------------------+--------+-------+ ~~~ ### Auto-Incrementing Is Not Always Sequential -It's a common misconception that the auto-incrementing types in PostgreSQL and MySQL generate strictly sequential values. In fact, each insert increases the sequence by one, even when the insert is not commited. This means that auto-incrementing types may leave gaps in a sequence. +It's a common misconception that the auto-incrementing types in PostgreSQL and MySQL generate strictly sequential values. In fact, each insert increases the sequence by one, even when the insert is not commited. This means that auto-incrementing types may leave gaps in a sequence. -To experience this for yourself, run through the following example in PostgreSQL: +To experience this for yourself, run through the following example in PostgreSQL: 1. Create a table with a `SERIAL` column. ~~~ sql > CREATE TABLE increment (a SERIAL PRIMARY KEY); - ~~~ + ~~~ -2. Run four transactions for inserting rows. +2. Run four transactions for inserting rows. ~~~ sql > BEGIN; INSERT INTO increment DEFAULT VALUES; ROLLBACK; > BEGIN; INSERT INTO increment DEFAULT VALUES; COMMIT; > BEGIN; INSERT INTO increment DEFAULT VALUES; ROLLBACK; > BEGIN; INSERT INTO increment DEFAULT VALUES; COMMIT; - ~~~ + ~~~ 3. View the rows created. @@ -108,8 +133,8 @@ In summary, the `SERIAL` type in PostgreSQL and CockroachDB, and the `AUTO_INCRE ## Supported Casting & Conversion -Because the `SERIAL` data type represents `INT` values automatically generated CockroachDB to uniquely identify rows, you cannot meaningfully [cast](data-types.html#data-type-conversions--casts) or convert `SERIAL` into other data types. If you do, its casting and conversion behavior is the same as [`INT`](int.html#supported-casting--conversion). +[Values of type `SERIAL` can be converted to other types like any `INT` values](int.html#supported-casting--conversion). ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html) diff --git a/sql-constants.md b/sql-constants.md new file mode 100644 index 00000000000..d5c3489925b --- /dev/null +++ b/sql-constants.md @@ -0,0 +1,236 @@ +--- +title: Constant Values +summary: SQL Constants represent a simple value that doesn't change. +toc: false +--- + +SQL Constants represent a simple value that doesn't change. + +
+ +## Introduction + +There are five categories of constants in CockroachDB: + +- [String literals](#string-literals): these define string values but their actual data type will + be inferred from context, for example, `'hello'`. +- [Numeric literals](#numeric-literals): these define numeric values but their actual data + type will be inferred from context, for example, `-12.3`. +- [Byte array literals](#byte-array-literals): these define byte array values with data type + `BYTES`, for example, `b'hello'`. +- [Interpreted literals](#interpreted-literals): these define arbitrary values with an explicit + type, for example, `INTERVAL '3 days'`. +- [Named constants](#named-constants): these have predefined values with a predefined + type, for example, `TRUE` or `NULL`. + +## String literals + +CockroachDB supports two formats for string literals: + +- [Standard SQL string literals](#standard-sql-string-literals). +- [String literals with C escape sequences](#string-literals-with-character-escapes). + +These format also allow arbitrary Unicode characters encoded as UTF-8. + +In any case, the actual data type of a string literal is determined +using the context where it appears. + +For example: + +| Expression | Data type of the string literal | +|------------|---------------------------------| +| `length('hello')` | `STRING` | +| `now() + '3 day'` | `INTERVAL` | +| `INSERT INTO tb(date_col) VALUES ('2013-01-02')` | `DATE` | + +In general, the data type of a string literal is that demanded by the +context if there is no ambiguity, or `STRING` otherwise. + +Check our blog for +[more information about the typing of string literals](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/). + +### Standard SQL string literals + +SQL string literals are formed by an arbitrary sequence of characters +enclosed between single quotes (`'`), for example, `'hello world'`. + +To include a single quote in the string, use a double single quote. +For example: + +~~~sql +> SELECT 'hello' as a, 'it''s a beautiful day' as b; +~~~ +~~~ ++-------+----------------------+ +| a | b | ++-------+----------------------+ +| hello | it's a beautiful day | ++-------+----------------------+ +~~~ + +For compatibility with the SQL standard, CockroachDB also recognizes +the following special syntax: two simple string literals separated by +a newline character are automatically concatenated together to form a +single constant. For example: + +~~~sql +> SELECT 'hello' +' world!' as a; +~~~ +~~~ ++--------------+ +| a | ++--------------+ +| hello world! | ++--------------+ +~~~ + +This special syntax only works if the two simple literals are +separated by a newline character. For example `'hello' ' world!'` +doesn't work. This is mandated by the SQL standard. + +### String literals with character escapes + +CockroachDB also supports string literals containing escape sequences +like in the programming language C. These are constructed by prefixing +the string literal with the letter `e`, for example, +`e'hello\nworld!'`. + +The following escape sequences are supported: + +Escape Sequence | Interpretation +----------------|--------------- +`\a` | ASCII code 7 (BEL) +`\b` | backspace (ASCII 8) +`\t` | tab (ASCII 9) +`\n` | newline (ASCII 10) +`\v` | vertical tab (ASCII 11) +`\f` | form feed (ASCII 12) +`\r` | carriage return (ASCII 13) +`\xHH` | hexadecimal byte value +`\ooo` | octal byte value +`\uXXXX` | 16-bit hexadecimal Unicode character value +`\UXXXXXXXX` | 32-bit hexadecimal Unicode character value + +For example, the `e'x61\141\u0061'` escape string represents the +hexadecimal byte, octal byte, and 16-bit hexadecimal Unicode character +values equivalent to the `'aaa'` string literal. + +## Numeric literals + +Numeric literals can have the following forms: + +~~~ + [+-]9999 + [+-]9999.[9999][e[+-]999] + [+-][9999].9999[e[+-]999] + [+-]9999e[+-]999 + [+-]0xAAAA +~~~ + +Some examples: + +~~~ + +4269 + 3.1415 + -.001 + 6.626e-34 + 50e6 + 0xcafe111 +~~~ + +The actual data type of a numeric constant depends both on the context +where it is used, its literal format, and its numeric value. + +| Syntax | Possible data types | +|--------|---------------------| +| Contains a decimal separator | `FLOAT`, `DECIMAL` | +| Contains an exponent | `FLOAT`, `DECIMAL` | +| Contains a value larger than 2^64 in magnitude | `FLOAT`, `DECIMAL` | +| Otherwise | `INT`, `DECIMAL`, `FLOAT` | + +Of the possible data types, which one is actually used is then further +refined depending on context. + +Check our blog for +[more information about the typing of numeric literals](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/). + +## Byte array literals + +CockroachDB supports two formats for byte array literals: + +- [Byte array literals with C escape sequences](#byte-array-literals-with-character-escapes) +- [Hexadecimal-encoded byte array literals](#hexadecimal-encoded-byte-array-literals) + +### Byte array literals with character escapes + +This uses the same syntax as [string literals containing character escapes](#string-literals-with-character-escapes), +using a `b` prefix instead of `e`. Any character escapes are interpreted like they +would be for string literals. + +For example: `b'hello,\x32world'` + +The two differences between byte array literals and string literals +with character escapes are as follows: + +- Byte array literals always have data type `BYTES`, whereas the data + type of a string literal depends on context. +- Byte array literals may contain invalid UTF-8 byte sequences, + whereas string literals must always contain valid UTF-8 sequences. + +### Hexadecimal-encoded byte array literals + +This is a CockroachDB-specific extension to express byte array +literals: the delimiter `x'` followed by an arbitrary sequence of +hexadecimal digits, followed by a closing `'`. + +For example, both `x'636174'` and `X'636174'` are equivalent to `b'cat'`. + +This feature is inspired from MySQL. + +## Interpreted literals + +A constant of any data type can be formed using either of the following formats: + +~~~ + type 'string' + 'string':::type +~~~ + +The value of the string part is used as input for the conversion function to the +specified data type, and the result is used as a constant with that data type. + +Examples: + +~~~ + DATE '2013-12-23' + BOOL 'FALSE' + '42.69':::INT + 'TRUE':::BOOL + '3 days':::INTERVAL +~~~ + +Additionally, for compatibility with PostgreSQL, the notation +`'string'::type` and `CAST('string' AS type)` is also recognized as an +interpreted literal. These are special cases of +[cast expressions](sql-expressions.html). + +For more information about the allowable format of interpreted +literals, refer to the "Syntax" section of the respective data types: +[`DATE`](date.html#syntax), [`INTERVAL`](interval.html#syntax), +[`TIMESTAMP`/`TIMESTAMPTZ`](timestamp.html#syntax). + +## Named constants + +CockroachDB recognizes the following SQL named constants: + +- `TRUE` and `FALSE`, the two possible values of data type `BOOL`. +- `NULL`, the special SQL symbol that indicates "no value present". + +Note that `NULL` is a valid constant for any type: its actual data +type during expression evaluation is determined based on context. + +## See Also + +- [Expressions](sql-expressions.html) +- [Data Types](data-types.html) diff --git a/sql-expressions.md b/sql-expressions.md new file mode 100644 index 00000000000..3e5169d9b2a --- /dev/null +++ b/sql-expressions.md @@ -0,0 +1,669 @@ +--- +title: Value Expressions +summary: Value expressions allow the computation of new values from basic parts. +toc: false +--- + +Most SQL statements can contain *value expressions* that compute new +values from data. For example, in the query `SELECT ceil(price) FROM +items`, the expression `ceil(price)` computes the rounded-up value of +the values from the `price` column. + +Value expressions produce values suitable to store in a single table +cell (one column of one row). They can be contrasted with +[table expressions](table-expressions.html), which produce results +structured as a table. + +The following sections provide details on each of these options. + +
+ +## Constants + +Constant expressions represent a simple value that doesn't change. +They are described further in section [SQL Constants](sql-constants.html). + +## Column References + +An expression in a query can refer to columns in the current data source in two ways: + +- Using the name of the column, e.g. "`price`" in `SELECT price FROM + items`. If the name of a column is also a + [SQL keyword](keywords-and-identifiers.html#keywords), the name must + be appropriately quoted. For example: `SELECT "Default" FROM + configuration`. + +- Using the ordinal position of the column. For example, `SELECT @1 FROM items` selects + the first column in `items`. + + *This is a CockroachDB SQL extension.* + + {{site.data.alerts.callout_danger}} + Ordinal references should be used with care in production + code! During schema updates, column ordinal positions can change and + invalidate existing queries that use ordinal positions based on a + previous version of the schema. + {{site.data.alerts.end}} + +## Unary and Binary Operations + +An expression prefixed by a unary operator, or two expressions +separated by a binary operator, form a new expression. + +CockroachDB supports the following operators: + +| Operator | Description | +|----------|-------------| +| `-` (unary) | numeric negation | +| `+` (unary) | no-op, exists only for symmetry with unary `-` | +| `~` (unary) | 64-bit binary complement | +| `NOT` (unary) | boolean/logical negation | +| `+` | addition | +| `-` | substraction | +| `*` | multiplication | +| `/` | numeric division | +| `//` | division with rounding ("integer division") | +| `%` | rest of division ("modulo") | +| `&` | bitwise AND | +| `|` | bitwise OR | +| `^`, `#` | bitwise XOR | +| `<<` | binary shift left | +| `>>` | binary shift right | +| `~` `!~`, `~*`, `!~*` | match using regular expression | +| `||` | concatenation for strings or byte arrays | +| `<`, `>`, `<=`, `>=`, `<>`, `!=`, `IS` | comparison | +| `LIKE`, `ILIKE`, `SIMILAR TO` | match using string pattern | +| `IN` | test for value in set | + +See also [this section over which data types are valid operands +for each operator](functions-and-operators.html#operators). + +### Value Comparisons + +The standard operators `<` (smaller than), `>` (greater than), `<=` +(lower than or equal to), `>=` (greater than or equal to), `=` +(equals), `<>` and `!=` (not equal to), `IS` (identical to), and `IS +NOT` (not identical to) can be applied to any pair of values from a +single data type, as well as some pairs of values from different data +types. + +See also [this section over which data types are valid operands +for each operator](functions-and-operators.html#operators). + +The following special rules apply: + +- `NULL` is always ordered smaller than every other value, even itself. +- `NULL` is never equal to anything via `=`, even `NULL`. To check + whether a value is `NULL`, use the `IS` operator or the conditional + expression `IFNULL(..)`. + +#### Typing rule + +All comparisons accept any combination of argument types and result in type `BOOL`. + +### Set Membership + +Syntax: + +~~~ + IN + IN ( ... subquery ... ) + + NOT IN + NOT IN ( ... subquery ... ) +~~~ + +Returns `TRUE` if and only if the value of the left operand is part of +the result of evaluating the right operand. + +For example: + +~~~sql +> SELECT a IN (1, 2, 3) FROM sometable; +> SELECT a IN (SELECT * FROM allowedvalues) FROM sometable; +> SELECT ('x', 123) IN (SELECT * FROM rows); +~~~ + +#### Typing rule + +`IN` requires its right operand to be a homogenous tuple type and its left operand +to match the tuple element type. The result has type `BOOL`. + +### String Pattern Matching + +Syntax: + +~~~ + LIKE + ILIKE + NOT LIKE + NOT ILIKE +~~~ + +Evaluates both expressions as strings, then tests whether the string on the left +matches the pattern given on the right. Returns `TRUE` if a match is found +or `FALSE` otherwise, or the inverted value for the `NOT` variants. + +Patterns can contain `_` to match any single +character, or `%` to match any sequence of zero or more characters. +`ILIKE` causes the match to be tested case-insentively. + +For example: + +~~~sql +> SELECT 'monday' LIKE '%day' AS a, 'tuesday' LIKE 'tue_day' AS b, 'wednesday' ILIKE 'W%' AS c; +~~~ +~~~ ++------+------+------+ +| a | b | c | ++------+------+------+ +| true | true | true | ++------+------+------+ +~~~ + +#### Typing rule + +The operands must be either both `STRING` or both `BYTES`. The result has type `BOOL`. + +### String Matching Using POSIX Regular Expressions + +Syntax: + +~~~ + ~ + ~* + !~ + !~* +~~~ + +Evaluates both expressions as strings, then tests whether the string on the left +matches the pattern given on the right. Returns `TRUE` if a match is found +or `FALSE` otherwise, or the inverted value for the `!` variants. + +The pattern is expressed using +[POSIX regular expression syntax](https://en.wikipedia.org/wiki/Regular_expression). Unlike +`LIKE` patterns, a regular expression is allowed to match anywhere +inside a string, not only at the beginning. + +For example: + +~~~sql +> SELECT 'monday' ~ 'onday' AS a, 'tuEsday' ~ 't[uU][eE]sday' AS b, 'wednesday' ~* 'W.*y' AS c; +~~~ +~~~ ++------+------+------+ +| a | b | c | ++------+------+------+ +| true | true | true | ++------+------+------+ +~~~ + +#### Typing rule + +The operands must be either both `STRING` or both `BYTES`. The result has type `BOOL`. + +### String Matching Using SQL Regular Expressions + +Syntax: + +~~~ + SIMILAR TO + NOT SIMILAR TO +~~~ + +Evaluates both expressions as strings, then tests whether the string on the left +matches the pattern given on the right. Returns `TRUE` if a match is found +or `FALSE` otherwise, or the inverted value for the `NOT` variant. + +The pattern is expressed using the SQL standard's definition of a regular expression. +This is a mix of SQL `LIKE` patterns and POSIX regular expressions: + +- `_` and `%` denote any character or any string, respectively. +- `.` matches specifically the period character, unlike in POSIX where it is a wildcard. +- Most of the other POSIX syntax applies as usual. +- The pattern matches the entire string (as in `LIKE`, unlike POSIX regular expressions). + +For example: + +~~~sql +> SELECT 'monday' SIMILAR TO '_onday' AS a, 'tuEsday' SIMILAR TO 't[uU][eE]sday' AS b, 'wednesday' SIMILAR TO 'w%y' AS c; +~~~ +~~~ ++------+------+------+ +| a | b | c | ++------+------+------+ +| true | true | true | ++------+------+------+ +~~~ + +#### Typing rule + +The operands must be either both `STRING` or both `BYTES`. The result has type `BOOL`. + +### Operator Precedence + +CockroachDB uses the following grouping precedence of +operators in expressions: + +| Level | Operators | +|-------|-----------| +| 1 | `~` (unary) | +| 2 | `-` (unary) | +| 3 | `*`, `/`, `//`, `%` | +| 4 | `+`, `-` (binary) | +| 5 | `<<`, `>>` | +| 6 | `&` | +| 7 | `^`, `#` | +| 8 | `|` | +| 9 | `||` | +| 10 | `IN`, `LIKE`, `ILIKE`, `SIMILAR TO`, `!~`, `!~*` `~*`, `~` (binary) | +| 11 | `<` `>` `=` `<=` `>=` `<>` `!=` | +| 12 | `IS` | +| 13 | `NOT` | + +## Function Calls and SQL Special Forms + +General syntax: + +~~~ + ( ) +~~~ + +A built-in function name followed by an opening parenthesis, followed +by a comma-separated list of expressions, followed by a closing +parenthesis. + +This applies the named function to the arguments between the parentheses. +See [the separate section on supported built-in functions](functions-and-operators.html). + +In addition, the following SQL special forms are also supported: + +| Special form | Equivalent to | +|------------------------------------------------------------|---------------| +| `EXTRACT( FROM )` | `extract("", )` | +| `EXTRACT_DURATION( FROM )` | `extract_duration("", )` | +| `OVERLAY( PLACING FROM FOR )` | `overlay(, , , )` | +| `OVERLAY( PLACING FROM )` | `overlay(, , )` | +| `POSITION( IN )` | `strpos(, )` | +| `SUBSTRING( FROM FOR )` | `substring(, , )` | +| `SUBSTRING( FOR FROM )` | `substring(, , )` | +| `SUBSTRING( FOR )` | `substring(, 1, )` | +| `SUBSTRING( FROM )` | `substring(, )` | +| `TRIM( FROM )` | `btrim(, )` | +| `TRIM(FROM )` | `btrim()` | +| `TRIM(, )` | `btrim(, )` | +| `TRIM(LEADING FROM )` | `ltrim(, )` | +| `TRIM(LEADING FROM )` | `ltrim()` | +| `TRIM(TRAILING FROM )` | `rtrim(, )` | +| `TRIM(TRAILING FROM )` | `rtrim()` | +| `CURRENT_DATE` | `current_date()` | +| `CURRENT_TIMESTAMP` | `current_timestamp()` | + +### Typing rule + +In general, a function call requires the arguments to be of the types +accepted by the function, and returns a value of the type determined +by the function. + +However, the typing of function calls is complicated by the fact +SQL supports function overloading. [See our blog post for more details](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/). + +## Subscripted Expressions + +It is possible to access one item in an array value using the `[` ... `]` operator. + +For example, if the name `a` refers to an array of 10 +values, `a[3]` will retrieve the 3rd value. The first value has index +1. + +If the index is smaller or equal to 0, or larger than the size of the array, then +the result of the subscripted expression is `NULL`. + +### Typing rule + +The subscripted expression must have an array type; the index expression +must have type `INT`. The result has the element type of the +subscripted expression. + +## Conditional Expressions and Boolean Short-Circuit Operations + +Expressions can test a conditional expression and, depending on whether +or which condition is satisfied, evaluate to one or more additional +operands. + +These expression formats share the following property: some of their +operands are only evaluated if a condition is true. This matters +especially when an operand would be invalid otherwise. For example, +`IF(a=0, 0, x/a)` returns 0 if `a` is 0, and `x/a` otherwise. + +### `IF` Expressions + +Syntax: + +~~~ + IF ( , , ) +~~~ + +Evaluates ``, then evaluates `` if the condition is true, +or `` otherwise. + +#### Typing rule + +The condition must have type `BOOL`, and the two remaining expressions +must have the same type. The result has the same type as the +expression that was evaluated. + +### `CASE` Expressions + +Syntax: + +~~~ + CASE + WHEN THEN + [ WHEN THEN ] ... + [ ELSE ] + END +~~~ + +Evaluates ``, then picks the `WHEN` branch where `` is +equal to ``, then evaluates and returns the corresponding `THEN` +expression. If no `WHEN` branch matches, the `ELSE` expression is +evaluated and returned, if any. Otherwise, `NULL` is returned. + +#### Typing rule + +The condition and the `WHEN` expressions must have the same type. +The `THEN` expressions and the `ELSE` expression, if any, must have the same type. +The result has the same type as the `THEN`/`ELSE` expressions. + +### `NULLIF` Expressions + +Syntax: + +~~~ + NULLIF ( , ) +~~~ + +Equivalent to: `IF ( = , NULL, )` + +#### Typing rule + +Both operands must have the same type, which is also the type of the result. + +### `COALESCE` and `IFNULL` Expressions + +Syntax: + +~~~ + IFNULL ( , ) + COALESCE ( [, [, ] ...] ) +~~~ + +`COALESCE` evaluates the first expression first. If its value is not +`NULL`, its value is returned directly. Otherwise, it returns the +result of applying `COALESCE` on the remaining expressions. If all the +expressions are `NULL`, `NULL` is returned. + +`IFNULL(a, b)` is equivalent to `COALESCE(a, b)`. + +#### Typing rule + +The operands must have the same type, which is also the type of the result. + +### `AND` and `OR`: Boolean Short-Circuit Comparisons + +Syntax: + +~~~ + AND + OR +~~~ + +These operators compute the boolean AND or OR function of their +operands, using short-circuit evaluation: + +- Both operators first evaluate their left operand. +- If the resulting value is `TRUE`, `OR` returns `TRUE` directly and + does not evaluate its right operand (short circuit), whereas `AND` + evaluates and returns the value of the right operand. +- If the resulting value of the left operand is `FALSE` or `NULL`, `AND` + returns `FALSE` directly and does not evaluate its right operand, + whereas `OR` evaluates and returns the value of the right operand. + +### Typing rule + +The operands must have type `BOOL`. The result has type `BOOL`. + +## Aggregate Expressions + +An aggregate expression has the same syntax as a function call, with a special +case for `COUNT`: + +~~~ + ( ) + COUNT ( * ) +~~~ + +The difference between aggregate expressions and function calls is +that the former use +[aggregate functions](functions-and-operators.html#aggregate-functions) +and can only appear in the list of rendered expressions in a +[`SELECT` clause](select.html). + +An aggregate expression computes a combined value, depending on +which aggregate function is used, across all the rows currently +selected. + +### Typing rule + +[The operand and return types are determined like for regular function calls](#function-calls-and-sql-special-forms). + +## Window Function Calls + +A window function call has the syntax of a function call followed by an `OVER` clause: + +~~~ + ( ) OVER + ( * ) OVER +~~~ + +It represents the application of a window or aggregate function over a +subset ("window") of the rows selected by a query. + +### Typing rule + +[The operand and return types are determined like for regular function calls](#function-calls-and-sql-special-forms). + +## Explicit Type Coercions + +Syntax: + +~~~ + :: + CAST ( AS ) +~~~ + +Evaluates the expression and converts the resulting value to the +specified type. An error is reported if the conversion is invalid. + +For example: `CAST(now() AS DATE)` + +Note that in many cases a type annotation is preferrable to a type +coercion. See the section on +[type annotations](#explicitly-typed-expressions) below for more +details. + +### Typing rule + +The operand can have any type. +The result has the type specified in the `CAST` expression. + +As a special case, if the operand is a literal, a constant expression +or a placeholder, the `CAST` type is used to guide the typing of the +operand. [See our blog post for more details](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/). + +## Collation Expressions + +Syntax: + +~~~ + COLLATE +~~~ + +Evaluates the expression and converts its result to a collated string +with the specified collation. + +For example: `'a' COLLATE de` + +### Typing rule + +The operand must have type `STRING`. The result has type `COLLATEDSTRING`. + +## Existence Test on the Result of Subqueries + +Syntax: + +~~~ + EXISTS ( ... subquery ... ) + NOT EXISTS ( ... subquery ... ) +~~~ + +Evaluates the subquery and then returns `TRUE` or `FALSE` depending on +whether the subquery returned any row (for `EXISTS`) or didn't return +any row (for `NOT EXISTS`). + +### Typing rule + +The operand can have any table type. The result has type `BOOL`. + +## Scalar Subqueries + +Syntax: + +~~~ + ( ... subquery ... ) +~~~ + +Evaluates the subquery, asserts that it returns a single row and single column, +and then evaluates to the value of that single cell. + +For example: + +~~~sql +> SELECT (SELECT COUNT(*) FROM users) > (SELECT COUNT(*) FROM admins); +~~~ + +returns `TRUE` if there are more rows in table `users` than in table +`admins`. + +### Typing rule + +The operand must have a table type with only one column. +The result has the type of that single column. + +## Array Constructors + +Syntax: + +~~~ + ARRAY[ , , ... ] +~~~ + +Evaluates to an array containing the specified values. + +For example: + +~~~sql +> SELECT ARRAY[1,2,3] AS a; +~~~ +~~~ ++---------+ +| a | ++---------+ +| {1,2,3} | ++---------+ +~~~ + +The data type of the array is inferred from the values of the provided +expressions. All the positions in the array must have the same data type. + +If there are no expressions specified (empty array), or +all the values are `NULL`, then the type of the array must be +specified explicitly using a type annotation. For example: + +~~~sql +> SELECT ARRAY[]:::int[]; +~~~ + +### Typing rule + +The operands must all have the same type. +The result has the array type with the operand type as element type. + +## Tuple Constructor + +Syntax: + +~~~ + (, , ...) + ROW (, , ...) +~~~ + +Evaluates to a tuple containing the values of the provided expressions. + +For example: + +~~~sql +> SELECT ('x', 123, 12.3) AS a; +~~~ +~~~ ++----------------+ +| a | ++----------------+ +| ('x',123,12.3) | ++----------------+ +~~~ + +The data type of the resulting tuple is inferred from the values. +Each position in a tuple can have a distinct data type. + +### Typing rule + +The operands can have any type. +The result has a tuple type whose item types are the types of the operands. + +## Explicitly Typed Expressions + +Syntax: + +~~~ + ::: + ANNOTATE_TYPE(, ) +~~~ + +Evaluates to the given expression, requiring the expression to have +the given type. If the expression doesn't have the given type, an +error is returned. + +Type annotations are specially useful to guide the arithmetic on +numeric values. For example: + +~~~sql +> SELECT (1 / 0):::FLOAT; --> +Inf +> SELECT (1 / 0); --> error "division by zero" +> SELECT (1 / 0)::FLOAT; --> error "division by zero" +~~~ + +Type annotations are also different from cast expressions (see above) in +that they do not cause the value to be converted. For example, +`now()::DATE` converts the current timestamp to a date value (and +discards the current time), whereas `now():::DATE` triggers an error +message (that `now()` does not have type `DATE`). + +Check our blog for +[more information about context-dependent typing](https://www.cockroachlabs.com/blog/revisiting-sql-typing-in-cockroachdb/). + +### Typing rule + +The operand must be implicitly coercible to the given type. +The result has the given type. diff --git a/sql-feature-support.md b/sql-feature-support.md index a27be2916ec..6f2c8359197 100644 --- a/sql-feature-support.md +++ b/sql-feature-support.md @@ -41,7 +41,7 @@ table tr td:nth-child(2) { | JSON | Planned | Common Extension | [GitHub Issue tracking JSON support](https://github.com/cockroachdb/cockroach/issues/2969) | | XML | ✗ | Standard | XML data can be stored as `BYTES`, but we do not offer XML parsing. | | `UNSIGNED INT` | ✗ | Common Extension | `UNSIGNED INT` causes numerous casting issues, so we don't plan to support it. | -| `SET`, `ENUM` | ✗ | MySQL, Postgres Extension | Only allow rows to contain values from a defined set of terms. | +| `SET`, `ENUM` | ✗ | MySQL, PostgreSQL Extension | Only allow rows to contain values from a defined set of terms. | ### Constraints @@ -96,9 +96,8 @@ table tr td:nth-child(2) { | Component | Supported | Type | Details | |-----------|-----------|------|---------| | Common statements | ✓ | Standard | [SQL Statements documentation](sql-statements.html) | -| `UPSERT` | ✓ | Postgres, MSSQL Extension | [`UPSERT` documentation](upsert.html) | +| `UPSERT` | ✓ | PostgreSQL, MSSQL Extension | [`UPSERT` documentation](upsert.html) | | `EXPLAIN` | ✓ | Common Extension | [`EXPLAIN` documentation](explain.html) | -| `JOIN` (`INNER`, `LEFT`, `RIGHT`, `FULL`, `CROSS`) | Functional | Standard | Currently works only with small data sets; find more info in our [blog post](https://www.cockroachlabs.com/blog/cockroachdbs-first-join/) | | `SELECT INTO` | Alternative | Common Extension | You can replicate similar functionality using [`CREATE TABLE`](create-table.html) and then `INSERT INTO ... SELECT ...`. | ### Clauses @@ -109,25 +108,39 @@ table tr td:nth-child(2) { | `LIMIT` | ✓ | Common Extension | Limit the number of rows a statement returns. | | `LIMIT` with `OFFSET` | ✓ | Common Extension | Skip a number of rows, and then limit the size of the return set. | | `RETURNING` | ✓ | Common Extension | Retrieve a table of rows statements affect. | -| Subqueries | Partial | Standard | Non-correlated subqueries are supported; correlated are not. Currently works only with small data sets. | -| `EXISTS` | Partial | Standard | Non-correlated subqueries are supported; correlated are not. Currently works only with small data sets. | -### Functions +### Table Expressions | Component | Supported | Type | Details | |-----------|-----------|------|---------| -| Common functions | ✓ | Standard | [Functions documentation](functions-and-operators.html#built-in-functions) | -| Common operators | ✓ | Standard | [Operators documentation](functions-and-operators.html#operators) | +| Table and View references | ✓ | Standard | [Table expressions documentation](table-expressions.html#table-or-view-names) | +| `AS` in table expressions | ✓ | Standard | [Aliased table expressions documentation](table-expressions.html#aliased-table-expressions) | +| `JOIN` (`INNER`, `LEFT`, `RIGHT`, `FULL`, `CROSS`) | Functional | Standard | [Join expressions documentation](table-expressions.html#join-expressions) | +| Sub-queries as table expressions | Partial | Standard | Non-correlated subqueries are [supported](table-expressions.html#subqueries-as-table-expressions); correlated are not. | +| Table generator functions | Partial | PostgreSQL Extension | [Table generator functions documentation](table-expressions.html#table-generator-functions) | +| `WITH ORDINALITY` | ✓ | CockroachDB Extension | [Ordinality annotation documentation](table-expressions.html#ordinality-annotation) | -### Conditional Expressions +### Value Expressions and Boolean Formulas | Component | Supported | Type | Details | |-----------|-----------|------|---------| -| `CASE` | ✓ | Standard | Return values based on if/then cases. | -| `NULLIF` | ✓ | Standard | Return *NULL* if values are equal. | -| `COALESCE` | ✓ | Standard | Return the first non-NULL column. | - -### Permissions +| Common functions | ✓ | Standard | [Functions calls and SQL special forms documentation](sql-expressions.html#function-calls-and-sql-special-forms) +| Common operators | ✓ | Standard | [Operators documentation](sql-expressions.html#unary-and-binary-operations) | +| `IF`/`CASE`/`NULLIF` | ✓ | Standard | [Conditional expressions documentation](sql-expressions.html#conditional-expressions-and-boolean-short-circuit-operations) | +| `COALESCE`/`IFNULL` | ✓ | Standard | [Conditional expressions documentation](sql-expressions.html#conditional-expressions-and-boolean-short-circuit-operations) | +| `AND`/`OR` | ✓ | Standard | [Conditional expressions documentation](sql-expressions.html#conditional-expressions-and-boolean-short-circuit-operations) | +| `LIKE`/`ILIKE` | ✓ | Standard | [String pattern matching documentation](sql-expressions.html#string-pattern-matching) | +| `SIMILAR TO` | ✓ | Standard | [SQL regexp pattern matching documentation](sql-expressions.html#string-matching-using-sql-regular-expressions) | +| Matching using POSIX regular expressions | ✓ | Common Extension | [POSIX regexp pattern matching documentation](sql-expressions.html#string-matching-using-posix-regular-expressions) | +| `EXISTS` | Partial | Standard | Non-correlated subqueries are [supported](sql-expressions.html#existence-test-on-the-result-of-subqueries); correlated are not. Currently works only with small data sets. | +| Scalar subqueries | Partial | Standard | Non-correlated subqueries are [supported](sql-expressions.html#scalar-subqueries); correlated are not. Currently works only with small data sets. | +| Bitwise arithmetic | ✓ | Common Extension | [Operators documentation](sql-expressions.html#unary-and-binary-operations) | +| Array constructors and subscripting | Partial | PostgreSQL Extension | Array expression documentation: [Constructor syntax](sql-expressions.html#array-constructors) and [Subscripting](sql-expressions.html#subscripted-expressions) | +| `COLLATE`| Partial | Standard | [Collation expressions documentation](sql-expressions.html#collation-expressions) | +| Column ordinal references | ✓ | CockroachDB Extension | [Column references documentation](sql-expressions.html#column-references) | +| Type annotations | ✓ | CockroachDB Extension | [Type annotations documentation](sql-expressions.html#explicitly-typed-expressions) | + +## Permissions | Component | Supported | Type | Details | |-----------|-----------|------|---------| @@ -142,9 +155,9 @@ table tr td:nth-child(2) { | Interleaved tables | ✓ | CockroachDB Extension | [Interleaved Tables documentation](interleave-in-parent.html) | | Information Schema | ✓ | Standard | [Information Schema documentation](information-schema.html) | Views | ✓ | Standard | [Views documentation](views.html) | +| Window functions | Partial | Common Extension | Perform calculations related on a selected row. | | Common Table Expressions | Planned | Common Extension | Similar to Views, though they are not stored. | | Stored Procedures | Planned | Common Extension | Execute a procedure explicitly. | -| Window functions | Planned | Common Extension | Perform calculations related on a selected row. | | Cursors | ✗ | Standard | Traverse a table's rows. | | Triggers | ✗ | Standard | Execute a set of commands whenever a specified event occurs. | | Sequences | ✗ | Common Extension | Create a numeric sequence. Given CockroachDB's distributed architecture, sequences are not viable. | diff --git a/sql-statements.md b/sql-statements.md index d17b9d4d6a7..30c02c7a83e 100644 --- a/sql-statements.md +++ b/sql-statements.md @@ -6,55 +6,81 @@ toc: false CockroachDB supports the following SQL statements. Click a statement for more details. -Statement | Usage +## Query and Update Statements + +Statement | Usage +----------|------------ +[`CREATE TABLE AS`](create-table-as.html) | Create a new table in a database using the results from a `SELECT` statement. +[`DELETE`](delete.html) | Delete specific rows from a table. +[`EXPLAIN`](explain.html) | View debugging and analysis details for a `SELECT`, `INSERT`, `UPDATE`, or `DELETE` statement. +[`INSERT`](insert.html) | Insert rows into a table. +[`SELECT`](select.html) | Select rows from a table. +[`TRUNCATE`](truncate.html) | Deletes all rows from specified tables. +[`UPDATE`](update.html) | Update rows in a table. +[`UPSERT`](upsert.html) | Insert rows that do not violate uniqueness constraints; update rows that do. + +## Data Definition Statements + +Statement | Usage ----------|------------ [`ADD COLUMN`](add-column.html) | Add columns to a table. [`ADD CONSTRAINT`](add-constraint.html) | Add a constraint to a column. [`ALTER COLUMN`](alter-column.html) | Change a column's [Default constraint](default-value.html) or drop the [Not Null constraint](not-null.html). [`ALTER TABLE`](alter-table.html) | Apply a schema change to a table. [`ALTER VIEW`](alter-view.html) | Rename a view. -[`BEGIN`](begin-transaction.html)| Initiate a [transaction](transactions.html). -[`COMMIT`](commit-transaction.html) | Commit the current [transaction](transactions.html). [`CREATE DATABASE`](create-database.html) | Create a new database. [`CREATE INDEX`](create-index.html) | Create an index for a table. -[`CREATE TABLE`](create-table.html) | Create a new table in a database. +[`CREATE TABLE`](create-table.html) | Create a new table in a database. [`CREATE TABLE AS`](create-table-as.html) | Create a new table in a database using the results from a `SELECT` statement. -[`CREATE USER`](create-user.html) | Creates a SQL user, which lets you control [privileges](privileges.html) on your databases and tables. [`CREATE VIEW`](create-view.html) | Create a new [view](views.html) in a database. -[`DELETE`](delete.html) | Delete specific rows from a table. [`DROP COLUMN`](drop-column.html) | Remove columns from a table. [`DROP CONSTRAINT`](drop-constraint.html) | Remove constraints from a column. [`DROP DATABASE`](drop-database.html) | Remove a database and all its objects. [`DROP INDEX`](drop-index.html) | Remove an index for a table. [`DROP TABLE`](drop-table.html) | Remove a table. [`DROP VIEW`](drop-view.html)| Remove a view. -[`EXPLAIN`](explain.html) | View debugging and analysis details for a `SELECT`, `INSERT`, `UPDATE`, or `DELETE` statement. -[`GRANT`](grant.html) | Grant privileges to users. -[`INSERT`](insert.html) | Insert rows into a table. [`RENAME COLUMN`](rename-column.html) | Rename a column in a table. [`RENAME DATABASE`](rename-database.html) | Rename a database. [`RENAME INDEX`](rename-index.html) | Rename an index for a table. [`RENAME TABLE`](rename-table.html) | Rename a table or move a table between databases. -[`RELEASE SAVEPOINT`](release-savepoint.html) | When using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), commit the transaction's changes once there are no retryable errors. -[`REVOKE`](revoke.html) | Revoke privileges from users. -[`ROLLBACK`](rollback-transaction.html) | Discard all updates made by the current [transaction](transactions.html) or, when using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), rollback to the `cockroach_restart` savepoint and retry the transaction. -[`SELECT`](select.html) | Select rows from a table. -[`SET DATABASE`](set-database.html) | Set the default database for the session. -[`SET TIME ZONE`](set-time-zone.html) | Set the default time zone for the session. -[`SET TRANSACTION`](set-transaction.html) | Set the isolation level or priority for the session or for an individual [transaction](transactions.html). -[`SHOW ALL`](show-all.html) | List all current run-time settings. [`SHOW COLUMNS`](show-columns.html) | View details about columns in a table. [`SHOW CONSTRAINTS`](show-constraints.html) | List constraints on a table. [`SHOW CREATE TABLE`](show-create-table.html) | View the `CREATE TABLE` statement that would create a carbon copy of the specified table. [`SHOW CREATE VIEW`](show-create-view.html) | View the `CREATE VIEW` statement that would create a carbon copy of the specified view. -[`SHOW DATABASE`](show-database.html) | List the default database for the session. [`SHOW DATABASES`](show-databases.html) | List databases in the cluster. -[`SHOW GRANTS`](show-grants.html) | View privileges granted to users. -[`SHOW INDEX`](show-index.html) | View index information for a table. +[`SHOW INDEX`](show-index.html) | View index information for a table. [`SHOW TABLES`](show-tables.html) | List tables in a database. -[`SHOW TIME ZONE`](show-time-zone.html) | View the default time zone for the session. + +## Transaction Management Statements + +Statement | Usage +----------|------------ +[`BEGIN`](begin-transaction.html)| Initiate a [transaction](transactions.html). +[`COMMIT`](commit-transaction.html) | Commit the current [transaction](transactions.html). +[`RELEASE SAVEPOINT`](release-savepoint.html) | When using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), commit the transaction's changes once there are no retryable errors. +[`ROLLBACK`](rollback-transaction.html) | Discard all updates made by the current [transaction](transactions.html) or, when using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), rollback to the `cockroach_restart` savepoint and retry the transaction. +[`SAVEPOINT`](savepoint.html) | When using the CockroachDB-provided function for client-side [transaction retries](transactions.html#transaction-retries), start a retryable transaction. +[`SET TRANSACTION`](set-transaction.html) | Set the isolation level or priority for the session or for an individual [transaction](transactions.html). [`SHOW TRANSACTION`](show-transaction.html) | View the isolation level or priority for the session or for an individual [transaction](transactions.html). + +## Privilege Management Statements + +Statement | Usage +----------|------------ +[`CREATE USER`](create-user.html) | Creates a SQL user, which lets you control [privileges](privileges.html) on your databases and tables. +[`GRANT`](grant.html) | Grant privileges to users. +[`REVOKE`](revoke.html) | Revoke privileges from users. +[`SHOW GRANTS`](show-grants.html) | View privileges granted to users. [`SHOW USERS`](show-users.html) | Lists the users for all databases. -[`TRUNCATE`](truncate.html) | Deletes all rows from specified tables. -[`UPDATE`](update.html) | Update rows in a table. -[`UPSERT`](upsert.html) | Insert rows that do not violate uniqueness constraints; update rows that do. + +## Session Management Statements + +Statement | Usage +----------|------------ +[`SET DATABASE`](set-database.html) | Set the default database for the session. +[`SET TIME ZONE`](set-time-zone.html) | Set the default time zone for the session. +[`SET TRANSACTION`](set-transaction.html) | Set the isolation level or priority for the session or for an individual [transaction](transactions.html). +[`SHOW ALL`](show-all.html) | List all current run-time settings. +[`SHOW DATABASE`](show-database.html) | List the default database for the session. +[`SHOW TIME ZONE`](show-time-zone.html) | View the default time zone for the session. +[`SHOW TRANSACTION`](show-transaction.html) | View the isolation level or priority for the session or for an individual [transaction](transactions.html). diff --git a/string.md b/string.md index 2d1a5e426de..a9cd9f21a26 100644 --- a/string.md +++ b/string.md @@ -37,37 +37,14 @@ When inserting a string: - If the value is cast as a string with a length limit (e.g., `CAST('hello world' AS STRING(5))`), CockroachDB truncates to the limit. - If the value is under the column's length limit, CockroachDB does **not** add padding. This applies to `STRING(n)` and all its aliases. -## Formats +## Syntax -A `STRING` column accepts Unicode string literals, hexadecimal string literals, and escape strings. +A value of type `STRING` can be expressed using a variety of formats. +See [string literals](sql-constants.html#string-literals) for more details. -### String Literal - -When inserting a string literal into a `STRING` column, format the value as a valid UTF-8 character sequence within single quotes, e.g., `'a1b2c3'`. - -### Hexadecimal-Encoded String Literal - -When inserting a hexadecimal-encoded string literal into a `STRING` column, format the value as `x` or `X` followed by hexadecimal digits in single quotes. For example, `x'636174'` or `X'636174'` correspond to the Unicode string literal `'cat'`. - -### Escape String - -When inserting an escape string into a `STRING` column, format the value as `e` or `E` followed by one or more of the following backslash escape sequences within single quotes: - -Backslash Escape Sequence | Interpretation ---------------------------|--------------- -`\b` | backspace -`\f` | form feed -`\n` | newline -`\r` | carriage return -`\t` | tab -`\xHH` | hexadecimal byte value -`\ooo` | octal byte value -`\uXXXX` | 16-bit hexadecimal Unicode character value -`\UXXXXXXXX` | 32-bit hexadecimal Unicode character value - -For example, the `e'x61\141\u0061'` escape string represents the hexadecimal byte, octal byte, and 16-bit hexadecimal Unicode character values equivalent to the `'aaa'` string literal. - -Note that any character not in the table above is taken literally in an escape string. Also, when continuing an escape string across lines, write `e` or `E` only before the first opening quote. +When printing out a `STRING` value in the [SQL shell](use-the-built-in-sql-client.html), the shell uses the simple +SQL string literal format if the value doesn't contain special character, +or the escaped format otherwise. ### Collations diff --git a/table-expressions.md b/table-expressions.md new file mode 100644 index 00000000000..6f418a925a3 --- /dev/null +++ b/table-expressions.md @@ -0,0 +1,205 @@ +--- +title: Table Expressions +summary: Table expressions define a data source in SELECT and INSERT statements. +toc: false +--- + +Table expressions define a data source in the `FROM` clause of +[`SELECT`](select.html) and [`INSERT`](insert.html) statements. + +
+ +## Introduction + +Table expressions are used prominently in the `SELECT` clause: + +~~~sql + SELECT ... FROM ,
, ... + INSERT INTO ... SELECT ... FROM
,
, ... +~~~ + +CockroachDB recognizes the following table expressions: + +- a [table or view name](#table-or-view-names); +- a [table generator function](#table-generator-functions); +- a `SELECT` or `VALUES` clause, as [a sub-query](#subqueries-as-table-expressions); +- an [aliased table expression](#aliased-table-expressions), using an `AS` clause; +- an explicit [`JOIN` expression](#join-expressions); +- another table expression [annoted with `WITH ORDINALITY`](#ordinality-annotation); or +- another table expression between parentheses. + +The following sections provide details on each of these options. + +In addition to this, the `FROM` clause itself accepts more than one +consecutive table expressions at the top level, separated by +commas. This is a shorthand notation for `CROSS JOIN`, documented in +the `JOIN` syntax below. + +## Table or View Names + +Syntax: + +~~~ + identifier + identifier.identifier +~~~ + +A single SQL identifier in a table expression context designates +the contents of the table or [view](views.html) with that name +in the current database, as configured by [`SET DATABASE`](set-database.html). + +If the name is prefixed by another identifier and a period, the table or view +is searched in the database with that name. + +For example: + +~~~sql + SELECT * FROM users -- uses table `users` in the current database; + SELECT * FROM mydb.users -- uses table `users` in database `mydb`; +~~~ + +## Table Generator Functions + +Syntax: + +~~~ + name ( arguments... ) +~~~ + +The name of a table generator function, followed by an opening +parenthesis, followed by zero or more expression arguments, followed +by a closing parenthesis. + +This designates a transient data source produced by the designated +function. + +Currently CockroachDB only supports the generator function +`pg_catalog.generate_series()`, for compatibility with +[the PostgreSQL set-generating function of the same name](https://www.postgresql.org/docs/9.6/static/functions-srf.html). + +For example: + +~~~sql +> SELECT * FROM generate_series(1, 3) +~~~ +~~~ ++-----------------+ +| generate_series | ++-----------------+ +| 1 | +| 2 | +| 3 | ++-----------------+ +~~~ + +## Subqueries as Table Expressions + +Syntax: + +~~~ + ( ... subquery ... ) +~~~ + +The subquery can be expressed either as a `SELECT` or `VALUES` clause. +The parentheses around the subquery are mandatory. + +For example: + +~~~sql + SELECT * FROM (VALUES(1), (2), (3)); + SELECT c+2 FROM (SELECT COUNT(*) AS c FROM users); +~~~ + +## Aliased Table Expressions + +Syntax: + +~~~ +
AS +
AS (, , ...) +~~~ + +In the first form, the table expression is equivalent to its left operand +with a new name for the entire table, and where columns retain their original name. + +In the second form, the columns are also renamed. + +For example: + +~~~sql + SELECT c.x FROM (SELECT COUNT(*) AS x FROM users) AS c; + SELECT c.x FROM (SELECT COUNT(*) FROM users) AS c(x); +~~~ + +## Join Expressions + +Syntax: + +~~~ + -- Inner joins: +
[ INNER ] JOIN
ON +
[ INNER ] JOIN
USING(, , ...) +
NATURAL [ INNER ] JOIN
+
CROSS JOIN
+ + -- Left outer joins: +
LEFT [ OUTER ] JOIN
ON +
LEFT [ OUTER ] JOIN
USING(, , ...) +
NATURAL LEFT [ OUTER ] JOIN
+ + -- Right outer joins: +
RIGHT [ OUTER ] JOIN
ON +
RIGHT [ OUTER ] JOIN
USING(, , ...) +
NATURAL RIGHT [ OUTER ] JOIN
+~~~ + +These expressions designate the +[SQL join operation](https://en.wikipedia.org/wiki/Join_(SQL)) on the +two operand table expressions. + +Currently works only with small data sets; find more info in our [blog post](https://www.cockroachlabs.com/blog/cockroachdbs-first-join/). + +## Ordinality Annotation + +Syntax: + +~~~ +
WITH ORDINALITY +~~~ + +Designates a data source equivalent to the table expression operand with +an extra "Ordinality" column that enumerates every row in the data source. + +For example: + +~~~sql +> SELECT * FROM (VALUES('a'),('b'),('c')); +~~~ +~~~ ++---------+ +| column1 | ++---------+ +| a | +| b | +| c | ++---------+ +~~~ + +~~~sql +> SELECT * FROM (VALUES ('a'), ('b'), ('c')) WITH ORDINALITY; +~~~ +~~~ ++---------+------------+ +| column1 | ordinality | ++---------+------------+ +| a | 1 | +| b | 2 | +| c | 3 | ++---------+------------+ +~~~ + +{{site.data.alerts.callout_info}} +WITH ORDINALITY necessarily prevents some optimizations of the +surrounding query. Use it sparingly if performance is a concern, and +always check the output of EXPLAIN in case of doubt. +{{site.data.alerts.end}} diff --git a/timestamp.md b/timestamp.md index a76df66c63a..74b46b2bfa1 100644 --- a/timestamp.md +++ b/timestamp.md @@ -12,17 +12,30 @@ The `TIMESTAMP` [data type](data-types.html) stores a date and time pair in UTC, In CockroachDB, `TIMESTAMP WITHOUT TIME ZONE` is an alias for `TIMESTAMP` and `TIMESTAMP WITH TIME ZONE` is an alias for `TIMESTAMPTZ`. -## Formats +## Syntax -When inserting into a `TIMESTAMP` column, use one of the following formats: +A constant value of type `TIMESTAMP`/`TIMESTAMPTZ` can be expressed using an +[interpreted literal](sql-constants.html#interpreted-literals), or a +string literal +[annotated with](sql-expressions.html#explicitly-typed-expressions) +type `TIMESTAMP`/`TIMESTAMPTZ` or +[coerced to](sql-expressions.html#explicit-type-coercions) type +`TIMESTAMP`/`TIMESTAMPTZ`. -- Date only: `TIMESTAMP '2016-01-25'` -- Date and Time: `TIMESTAMP '2016-01-25 10:10:10.555555'` -- ISO 8601: `TIMESTAMP '2016-01-25T10:10:10.555555'` +`TIMESTAMP` constants can be expressed using the +following string literal formats: -When inserting into a `TIMESTAMPTZ` column (with time zone offset from UTC), use the following format: `TIMESTAMPTZ '2016-01-25 10:10:10.555555-05:00'` +Format | Example +-------|-------- +Date only | `TIMESTAMP '2016-01-25'` +Date and Time | `TIMESTAMP '2016-01-25 10:10:10.555555'` +ISO 8601 | `TIMESTAMP '2016-01-25T10:10:10.555555'` -Alternatively, you can use a string literal, e.g., `'2016-01-25T10:10:10'` or `'2016-01-25 10:10:10.555555-05:00'`, which CockroachDB will resolve into the `TIMESTAMP` or `TIMESTAMPTZ` type. +To express a `TIMESTAMPTZ` value (with time zone offset from UTC), use +the following format: `TIMESTAMPTZ '2016-01-25 10:10:10.555555-05:00'` + +When it is unambiguous, a simple unannotated string literal can also +be automatically interpreted as type `TIMESTAMP` or `TIMESTAMPTZ`. Note that the fractional portion is optional and is rounded to microseconds (6 digits after decimal) for compatibility with the @@ -80,4 +93,4 @@ Type | Details ## See Also -[Data Types](data-types.html) \ No newline at end of file +[Data Types](data-types.html)