-
Notifications
You must be signed in to change notification settings - Fork 760
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* docs(pivot): add pivot * docs: add PIVOT and UNPIVOT
- Loading branch information
Showing
2 changed files
with
162 additions
and
0 deletions.
There are no files selected for viewing
85 changes: 85 additions & 0 deletions
85
docs/doc/14-sql-commands/20-query-syntax/05-query-pivot.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,85 @@ | ||
--- | ||
title: PIVOT | ||
--- | ||
|
||
The `PIVOT` operation in Databend allows you to transform a table by rotating it and aggregating results based on specified columns. | ||
|
||
It is a useful operation for summarizing and analyzing large amounts of data in a more readable format. In this document, we will explain the syntax and provide an example of how to use the `PIVOT` operation. | ||
|
||
**See also:** | ||
[UNPIVOT](./05-query-unpivot.md) | ||
|
||
|
||
## Syntax | ||
|
||
```sql | ||
SELECT ... | ||
FROM ... | ||
PIVOT ( <aggregate_function> ( <pivot_column> ) | ||
FOR <value_column> IN ( <pivot_value_1> [ , <pivot_value_2> ... ] ) ) | ||
|
||
[ ... ] | ||
``` | ||
|
||
Where: | ||
* `<aggregate_function>`: The aggregate function for combining the grouped values from `pivot_column`. | ||
* `<pivot_column>`: The column that will be aggregated using the specified `<aggregate_function>`. | ||
* `<value_column>`: The column whose unique values will become new columns in the pivoted result set. | ||
* `<pivot_value_N>`: A unique value from the `<value_column>` that will become a new column in the pivoted result set. | ||
|
||
|
||
## Examples | ||
|
||
Let's say we have a table called monthly_sales that contains sales data for different employees across different months. We can use the `PIVOT` operation to summarize the data and calculate the total sales for each employee in each month. | ||
|
||
### Creating and Inserting Data | ||
|
||
|
||
```sql | ||
-- Create the monthly_sales table | ||
CREATE TABLE monthly_sales( | ||
empid INT, | ||
amount INT, | ||
month VARCHAR | ||
); | ||
|
||
-- Insert sales data | ||
INSERT INTO monthly_sales VALUES | ||
(1, 10000, 'JAN'), | ||
(1, 400, 'JAN'), | ||
(2, 4500, 'JAN'), | ||
(2, 35000, 'JAN'), | ||
(1, 5000, 'FEB'), | ||
(1, 3000, 'FEB'), | ||
(2, 200, 'FEB'), | ||
(2, 90500, 'FEB'), | ||
(1, 6000, 'MAR'), | ||
(1, 5000, 'MAR'), | ||
(2, 2500, 'MAR'), | ||
(2, 9500, 'MAR'), | ||
(1, 8000, 'APR'), | ||
(1, 10000, 'APR'), | ||
(2, 800, 'APR'), | ||
(2, 4500, 'APR'); | ||
``` | ||
|
||
### Using PIVOT | ||
|
||
Now, we can use the `PIVOT` operation to calculate the total sales for each employee in each month. We will use the `SUM` aggregate function to calculate the total sales, and the MONTH column will be pivoted to create new columns for each month. | ||
|
||
```sql | ||
SELECT * | ||
FROM monthly_sales | ||
PIVOT(SUM(amount) FOR MONTH IN ('JAN', 'FEB', 'MAR', 'APR')) | ||
ORDER BY EMPID; | ||
``` | ||
|
||
Output: | ||
```sql | ||
+-------+-------+-------+-------+-------+ | ||
| empid | jan | feb | mar | apr | | ||
+-------+-------+-------+-------+-------+ | ||
| 1 | 10400 | 8000 | 11000 | 18000 | | ||
| 2 | 39500 | 90700 | 12000 | 5300 | | ||
+-------+-------+-------+-------+-------+ | ||
``` |
77 changes: 77 additions & 0 deletions
77
docs/doc/14-sql-commands/20-query-syntax/05-query-unpivot.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,77 @@ | ||
--- | ||
title: UNPIVOT | ||
--- | ||
|
||
The `UNPIVOT` operation rotates a table by transforming columns into rows. | ||
|
||
It is a relational operator that accepts two columns (from a table or subquery), along with a list of columns, and generates a row for each column specified in the list. In a query, it is specified in the FROM clause after the table name or subquery. | ||
|
||
**See also:** | ||
[PIVOT](./05-query-pivot.md) | ||
|
||
|
||
## Syntax | ||
|
||
```sql | ||
SELECT ... | ||
FROM ... | ||
UNPIVOT ( <value_column> | ||
FOR <name_column> IN ( <column_list> ) ) | ||
|
||
[ ... ] | ||
``` | ||
|
||
Where: | ||
* `<value_column>`: The column that will store the values extracted from the columns listed in `<column_list>`. | ||
* `<name_column>`: The column that will store the names of the columns from which the values were extracted. | ||
* `<column_list>`: The list of columns to be unpivoted, separated by commas. | ||
|
||
|
||
## Examples | ||
|
||
Let's unpivot the individual month columns to return a single sales value by month for each employee: | ||
|
||
### Creating and Inserting Data | ||
|
||
|
||
```sql | ||
-- Create the unpivoted_monthly_sales table | ||
CREATE TABLE unpivoted_monthly_sales( | ||
empid INT, | ||
jan INT, | ||
feb INT, | ||
mar INT, | ||
apr INT | ||
); | ||
|
||
-- Insert sales data | ||
INSERT INTO unpivoted_monthly_sales VALUES | ||
(1, 10400, 8000, 11000, 18000), | ||
(2, 39500, 90700, 12000, 5300); | ||
``` | ||
|
||
### Using UNPIVOT | ||
|
||
|
||
```sql | ||
SELECT * | ||
FROM unpivoted_monthly_sales | ||
UNPIVOT (amount | ||
FOR month IN (jan, feb, mar, apr)); | ||
``` | ||
|
||
Output: | ||
```sql | ||
+-------+-------+--------+ | ||
| empid | month | amount | | ||
+-------+-------+--------+ | ||
| 1 | jan | 10400 | | ||
| 1 | feb | 8000 | | ||
| 1 | mar | 11000 | | ||
| 1 | apr | 18000 | | ||
| 2 | jan | 39500 | | ||
| 2 | feb | 90700 | | ||
| 2 | mar | 12000 | | ||
| 2 | apr | 5300 | | ||
+-------+-------+--------+ | ||
``` |
5ddeabc
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
Successfully deployed to the following URLs:
databend – ./
databend.vercel.app
databend-git-main-databend.vercel.app
databend-databend.vercel.app
databend.rs