Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Update star.md #4220

Open
wants to merge 4 commits into
base: main
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
141 changes: 65 additions & 76 deletions docs/sql/expressions/star.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,105 +4,94 @@ title: Star Expression
railroad: expressions/star.js
---

## Examples

Select all columns present in the `FROM` clause:
## Syntax

```sql
SELECT * FROM table_name;
```
<div id="rrdiagram"></div>

Count the number of rows in a table:
The `*` expression can be used in a `SELECT` statement to select all columns that are projected in the `FROM` clause.

```sql
SELECT count(*) FROM table_name;
SELECT *
FROM tbl;
```

DuckDB offers a shorthand for `count(*)` expressions where the `*` may be omitted:

```sql
SELECT count() FROM table_name;
```
### `TABLE.*` and `STRUCT.*`

Select all columns from the table called `table_name`:
The `*` expression can be prepended by a table name to select only columns from that table.

```sql
SELECT table_name.*
FROM table_name
JOIN other_table_name USING (id);
```

Select all columns except the city column from the addresses table:
Similarly, the `*` expression can also be used to retrieve all keys from a struct as separate columns.
This is particularly useful when a prior operation creates a struct of unknown shape, or if a query must handle any potential struct keys.
See the [`STRUCT` data type]({% link docs/sql/data_types/struct.md %}) and [`STRUCT` functions]({% link docs/sql/functions/struct.md %}) pages for more details on working with structs.

For example:

```sql
SELECT * EXCLUDE (city)
FROM addresses;
SELECT st.* FROM (SELECT {'x': 1, 'y': 2, 'z': 3} AS st);
```

Select all columns from the addresses table, but replace city with `lower(city)`:
<div class="narrow_table"></div>

```sql
SELECT * REPLACE (lower(city) AS city)
FROM addresses;
```
| x | y | z |
|--:|--:|--:|
| 1 | 2 | 3 |

Select all columns matching the given expression:

```sql
SELECT COLUMNS(c -> c LIKE '%num%')
FROM addresses;
```
### `EXCLUDE` Clause

Select all columns matching the given regex from the table:
`EXCLUDE` allows us to exclude specific columns from the `*` expression.

```sql
SELECT COLUMNS('number\d+')
FROM addresses;
SELECT * EXCLUDE (col)
FROM tbl;
```

Select columns using a list:
### `REPLACE` Clause

`REPLACE` allows us to replace specific columns by alternative expressions.

```sql
SELECT COLUMNS(['city', 'zip_code'])
FROM addresses;
SELECT * REPLACE (col1 / 1_000 AS col1, col2 / 1_000 AS col2)
FROM tbl;
```

## Syntax

<div id="rrdiagram"></div>

## Star Expression
### `RENAME` Clause

The `*` expression can be used in a `SELECT` statement to select all columns that are projected in the `FROM` clause.
`RENAME` allows us to replace specific columns.

```sql
SELECT *
SELECT * RENAME (col1 AS height, col2 AS width)
FROM tbl;
```

The `*` expression can be modified using the `EXCLUDE` and `REPLACE`.
### Column Filtering via Pattern Matching Operators

### `EXCLUDE` Clause

`EXCLUDE` allows us to exclude specific columns from the `*` expression.
The [pattern matching operators]({% link docs/sql/functions/pattern_matching.md %}) `LIKE`, `GLOB`, `SIMILAR TO` and their variants allow us to select columns by matching their names to patterns.

```sql
SELECT * EXCLUDE (col)
SELECT * LIKE 'col%'
FROM tbl;
```

### `REPLACE` Clause

`REPLACE` allows us to replace specific values in columns as specified by an expression.
```sql
SELECT * GLOB 'col*'
FROM tbl;
```

```sql
SELECT * REPLACE (col / 1_000 AS col)
SELECT * SIMILAR TO 'col.'
FROM tbl;
```

## `COLUMNS` Expression

The `COLUMNS` expression can be used to execute the same expression on the values in multiple columns. For example:

The `COLUMNS` expression is similar to the regular star expression, but additionally allows us to execute the same expression on the resulting columns.

```sql
CREATE TABLE numbers (id INTEGER, number INTEGER);
Expand All @@ -116,8 +105,6 @@ SELECT min(COLUMNS(*)), count(COLUMNS(*)) FROM numbers;
|---:|-------:|---:|-------:|
| 1 | 10 | 3 | 2 |

The `*` expression in the `COLUMNS` statement can also contain `EXCLUDE` or `REPLACE`, similar to regular star expressions.

```sql
SELECT
min(COLUMNS(* REPLACE (number + id AS number))),
Expand All @@ -131,7 +118,7 @@ FROM numbers;
|---:|-----------------------------:|---:|
| 1 | 11 | 3 |

`COLUMNS` expressions can also be combined, as long as the `COLUMNS` contains the same (star) expression:
`COLUMNS` expressions can also be combined, as long as they contain the same star expression:

```sql
SELECT COLUMNS(*) + COLUMNS(*) FROM numbers;
Expand All @@ -145,6 +132,9 @@ SELECT COLUMNS(*) + COLUMNS(*) FROM numbers;
| 4 | 40 |
| 6 | NULL |


### `COLUMNS` Expression in a `WHERE` Clause

`COLUMNS` expressions can also be used in `WHERE` clauses. The conditions are applied to all columns and are combined using the logical `AND` operator.

```sql
Expand All @@ -165,9 +155,9 @@ WHERE COLUMNS(*) > 1; -- equivalent to: x > 1 AND y > 1 AND z > 1
|--:|--:|--:|
| 2 | 3 | 4 |

## `COLUMNS` Regular Expression
### Regular Expressions in a `COLUMNS` Expression

`COLUMNS` supports passing a regex in as a string constant:
`COLUMNS` expressions don't currently support the pattern matching operators, but they do supports regular expression matching by simply passing a string constant in place of the star:

```sql
SELECT COLUMNS('(id|numbers?)') FROM numbers;
Expand All @@ -181,9 +171,9 @@ SELECT COLUMNS('(id|numbers?)') FROM numbers;
| 2 | 20 |
| 3 | NULL |

### Renaming Columns Using a `COLUMNS` Expression
### Renaming Columns with Regular Expressions in a `COLUMNS` Expression

The matches of capture groups can be used to rename columns selected by a regular expression.
The matches of capture groups in regular expressions can be used to rename matching columns.
The capture groups are one-indexed; `\0` is the original column name.

For example, to select the first three letters of colum names, run:
Expand All @@ -207,7 +197,7 @@ CREATE TABLE tbl ("Foo:Bar" INTEGER, "Foo:Baz" INTEGER, "Foo:Qux" INTEGER);
SELECT COLUMNS('(\w*):(\w*)') AS '\1\2' FROM tbl;
```

## `COLUMNS` Lambda Function
### `COLUMNS` Lambda Function

`COLUMNS` also supports passing in a lambda function. The lambda function will be evaluated for all columns present in the `FROM` clause, and only columns that match the lambda function will be returned. This allows the execution of arbitrary expressions in order to select and rename columns.

Expand All @@ -223,6 +213,23 @@ SELECT COLUMNS(c -> c LIKE '%num%') FROM numbers;
| 20 |
| NULL |


### `COLUMNS` List

`COLUMNS` also supports passing in a list of column names.

```sql
SELECT COLUMNS(['id', 'num']) FROM numbers;
```

<div class="narrow_table"></div>

| id | num |
|---:|-----:|
| 1 | 10 |
| 2 | 20 |
| 3 | NULL |

## `*COLUMNS` Unpacked Columns

The `*COLUMNS` clause is a variation of `COLUMNS`, which supports all of the previously mentioned capabilities.
Expand Down Expand Up @@ -264,21 +271,3 @@ FROM (SELECT NULL a, 42 AS b, true AS c);
| result |
|-------:|
| 42 |

## `STRUCT.*`

The `*` expression can also be used to retrieve all keys from a struct as separate columns.
This is particularly useful when a prior operation creates a struct of unknown shape, or if a query must handle any potential struct keys.
See the [`STRUCT` data type]({% link docs/sql/data_types/struct.md %}) and [`STRUCT` functions]({% link docs/sql/functions/struct.md %}) pages for more details on working with structs.

For example:

```sql
SELECT st.* FROM (SELECT {'x': 1, 'y': 2, 'z': 3} AS st);
```

<div class="narrow_table"></div>

| x | y | z |
|--:|--:|--:|
| 1 | 2 | 3 |
39 changes: 31 additions & 8 deletions js/railroad.js
Original file line number Diff line number Diff line change
Expand Up @@ -1886,13 +1886,13 @@ function GenerateOrderBy(options) {
function GenerateStarOptions(options) {
return [
Optional(
Sequence([
Keyword("EXCLUDE"),
Keyword("("),
OneOrMore(Expression("exclude-name"), ","),
Keyword(")"),
]), "skip"),
Optional(
Choice(0, [
Sequence([
Keyword("EXCLUDE"),
Keyword("("),
OneOrMore(Expression("exclude-name"), ","),
Keyword(")"),
]),
Sequence([
Keyword("REPLACE"),
Keyword("("),
Expand All @@ -1902,7 +1902,30 @@ function GenerateStarOptions(options) {
Expression("column-name")
]), ","),
Keyword(")"),
]), "skip")
]),
Sequence([
Keyword("RENAME"),
Keyword("("),
OneOrMore(Sequence([
Expression("column-name"),
Keyword("AS"),
Expression("column-name")
]), ","),
Keyword(")"),
]),
Sequence([
Optional(Keyword("NOT"), "skip"),
Choice(0, [
Keyword("LIKE"),
Keyword("SIMILAR TO"),
Keyword("GLOB"),
Keyword("ILIKE"),
]),
Expression("pattern"),
]),
]),
"skip"
)
]
}

Expand Down