Skip to content

Commit 7f88f86

Browse files
authored
Merge pull request #3446 from Blargian/aggregate_combinators_examples_most_popular
Aggregate combinators examples
2 parents 788641c + bd63b9a commit 7f88f86

28 files changed

+2031
-0
lines changed
Lines changed: 58 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,58 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/anyIf'
3+
title: 'anyIf'
4+
description: 'Example of using the anyIf combinator'
5+
keywords: ['any', 'if', 'combinator', 'examples', 'anyIf']
6+
sidebar_label: 'anyIf'
7+
---
8+
9+
# anyIf {#avgif}
10+
11+
## Description {#description}
12+
13+
The [`If`](/sql-reference/aggregate-functions/combinators#-if) combinator can be applied to the [`any`](/sql-reference/aggregate-functions/reference/any)
14+
aggregate function to select the first encountered element from a given column
15+
that matches the given condition.
16+
17+
## Example Usage {#example-usage}
18+
19+
In this example, we'll create a table that stores sales data with success flags,
20+
and we'll use `anyIf` to select the first `transaction_id`s which are above and
21+
below an amount of 200.
22+
23+
We first create a table and insert data into it:
24+
25+
```sql title="Query"
26+
CREATE TABLE sales(
27+
transaction_id UInt32,
28+
amount Decimal(10,2),
29+
is_successful UInt8
30+
)
31+
ENGINE = MergeTree()
32+
ORDER BY tuple();
33+
34+
INSERT INTO sales VALUES
35+
(1, 100.00, 1),
36+
(2, 150.00, 1),
37+
(3, 155.00, 0),
38+
(4, 300.00, 1),
39+
(5, 250.50, 0),
40+
(6, 175.25, 1);
41+
```
42+
43+
```sql
44+
SELECT
45+
anyIf(transaction_id, amount < 200) as tid_lt_200,
46+
anyIf(transaction_id, amount > 200) as tid_gt_200
47+
FROM sales;
48+
```
49+
50+
```response title="Response"
51+
┌─tid_lt_200─┬─tid_gt_200─┐
52+
│ 1 │ 4 │
53+
└────────────┴────────────┘
54+
```
55+
56+
## See also {#see-also}
57+
- [`any`](/sql-reference/aggregate-functions/reference/any)
58+
- [`If combinator`](/sql-reference/aggregate-functions/combinators#-if)
Lines changed: 61 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,61 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/argMaxIf'
3+
title: 'argMaxIf'
4+
description: 'Example of using the argMaxIf combinator'
5+
keywords: ['argMax', 'if', 'combinator', 'examples', 'argMaxIf']
6+
sidebar_label: 'argMaxIf'
7+
---
8+
9+
# argMaxIf {#argmaxif}
10+
11+
## Description {#description}
12+
13+
The [`If`](/sql-reference/aggregate-functions/combinators#-if) combinator can be applied to the [`argMax`](/sql-reference/aggregate-functions/reference/argmax)
14+
function to find the value of `arg` that corresponds to the maximum value of `val` for rows where the condition is true,
15+
using the `argMaxIf` aggregate combinator function.
16+
17+
The `argMaxIf` function is useful when you need to find the value associated with
18+
the maximum value in a dataset, but only for rows that satisfy a specific
19+
condition.
20+
21+
## Example Usage {#example-usage}
22+
23+
In this example, we'll use a sample dataset of product sales to demonstrate how
24+
`argMaxIf` works. We'll find the product name that has the highest price, but
25+
only for products that have been sold at least 10 times.
26+
27+
```sql title="Query"
28+
CREATE TABLE product_sales
29+
(
30+
product_name String,
31+
price Decimal32(2),
32+
sales_count UInt32
33+
) ENGINE = Memory;
34+
35+
INSERT INTO product_sales VALUES
36+
('Laptop', 999.99, 10),
37+
('Phone', 499.99, 15),
38+
('Tablet', 299.99, 0),
39+
('Watch', 199.99, 5),
40+
('Headphones', 79.99, 20);
41+
42+
SELECT argMaxIf(product_name, price, sales_count >= 10) as most_expensive_popular_product
43+
FROM product_sales;
44+
```
45+
46+
The `argMaxIf` function will return the product name that has the highest price
47+
among all products that have been sold at least 10 times (sales_count >= 10).
48+
In this case, it will return 'Laptop' since it has the highest price (999.99)
49+
among the popular products.
50+
51+
```response title="Response"
52+
┌─most_expensi⋯lar_product─┐
53+
1. │ Laptop │
54+
└──────────────────────────┘
55+
```
56+
57+
## See also {#see-also}
58+
- [`argMax`](/sql-reference/aggregate-functions/reference/argmax)
59+
- [`argMin`](/sql-reference/aggregate-functions/reference/argmin)
60+
- [`argMinIf`](/examples/aggregate-function-combinators/argMinIf)
61+
- [`If combinator`](/sql-reference/aggregate-functions/combinators#-if)
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/argMinIf'
3+
title: 'argMinIf'
4+
description: 'Example of using the argMinIf combinator'
5+
keywords: ['argMin', 'if', 'combinator', 'examples', 'argMinIf']
6+
sidebar_label: 'argMinIf'
7+
---
8+
9+
# argMinIf {#argminif}
10+
11+
## Description {#description}
12+
13+
The [`If`](/sql-reference/aggregate-functions/combinators#-if) combinator can be applied to the [`argMin`](/sql-reference/aggregate-functions/reference/argmin)
14+
function to find the value of `arg` that corresponds to the minimum value of `val` for rows where the condition is true,
15+
using the `argMinIf` aggregate combinator function.
16+
17+
The `argMinIf` function is useful when you need to find the value associated
18+
with the minimum value in a dataset, but only for rows that satisfy a specific
19+
condition.
20+
21+
## Example Usage {#example-usage}
22+
23+
In this example, we'll create a table that stores product prices and their timestamps,
24+
and we'll use `argMinIf` to find the lowest price for each product when it's in stock.
25+
26+
```sql title="Query"
27+
CREATE TABLE product_prices(
28+
product_id UInt32,
29+
price Decimal(10,2),
30+
timestamp DateTime,
31+
in_stock UInt8
32+
) ENGINE = Log;
33+
34+
INSERT INTO product_prices VALUES
35+
(1, 10.99, '2024-01-01 10:00:00', 1),
36+
(1, 9.99, '2024-01-01 10:05:00', 1),
37+
(1, 11.99, '2024-01-01 10:10:00', 0),
38+
(2, 20.99, '2024-01-01 11:00:00', 1),
39+
(2, 19.99, '2024-01-01 11:05:00', 1),
40+
(2, 21.99, '2024-01-01 11:10:00', 1);
41+
42+
SELECT
43+
product_id,
44+
argMinIf(price, timestamp, in_stock = 1) as lowest_price_when_in_stock
45+
FROM product_prices
46+
GROUP BY product_id;
47+
```
48+
49+
The `argMinIf` function will find the price that corresponds to the earliest timestamp for each product,
50+
but only considering rows where `in_stock = 1`. For example:
51+
- Product 1: Among in-stock rows, 10.99 has the earliest timestamp (10:00:00)
52+
- Product 2: Among in-stock rows, 20.99 has the earliest timestamp (11:00:00)
53+
54+
```response title="Response"
55+
┌─product_id─┬─lowest_price_when_in_stock─┐
56+
1. │ 1 │ 10.99 │
57+
2. │ 2 │ 20.99 │
58+
└────────────┴────────────────────────────┘
59+
```
60+
61+
## See also {#see-also}
62+
- [`argMin`](/sql-reference/aggregate-functions/reference/argmin)
63+
- [`argMax`](/sql-reference/aggregate-functions/reference/argmax)
64+
- [`argMaxIf`](/examples/aggregate-function-combinators/argMaxIf)
65+
- [`If combinator`](/sql-reference/aggregate-functions/combinators#-if)
Lines changed: 53 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,53 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/avgIf'
3+
title: 'avgIf'
4+
description: 'Example of using the avgIf combinator'
5+
keywords: ['avg', 'if', 'combinator', 'examples', 'avgIf']
6+
sidebar_label: 'avgIf'
7+
---
8+
9+
# avgIf {#avgif}
10+
11+
## Description {#description}
12+
13+
The [`If`](/sql-reference/aggregate-functions/combinators#-if) combinator can be applied to the [`avg`](/sql-reference/aggregate-functions/reference/avg)
14+
function to calculate the arithmetic mean of values for rows where the condition is true,
15+
using the `avgIf` aggregate combinator function.
16+
17+
## Example Usage {#example-usage}
18+
19+
In this example, we'll create a table that stores sales data with success flags,
20+
and we'll use `avgIf` to calculate the average sale amount for successful transactions.
21+
22+
```sql title="Query"
23+
CREATE TABLE sales(
24+
transaction_id UInt32,
25+
amount Decimal(10,2),
26+
is_successful UInt8
27+
) ENGINE = Log;
28+
29+
INSERT INTO sales VALUES
30+
(1, 100.50, 1),
31+
(2, 200.75, 1),
32+
(3, 150.25, 0),
33+
(4, 300.00, 1),
34+
(5, 250.50, 0),
35+
(6, 175.25, 1);
36+
37+
SELECT
38+
avgIf(amount, is_successful = 1) as avg_successful_sale
39+
FROM sales;
40+
```
41+
42+
The `avgIf` function will calculate the average amount only for rows where `is_successful = 1`.
43+
In this case, it will average the amounts: 100.50, 200.75, 300.00, and 175.25.
44+
45+
```response title="Response"
46+
┌─avg_successful_sale─┐
47+
1. │ 193.88 │
48+
└─────────────────────┘
49+
```
50+
51+
## See also {#see-also}
52+
- [`avg`](/sql-reference/aggregate-functions/reference/avg)
53+
- [`If combinator`](/sql-reference/aggregate-functions/combinators#-if)
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/avgMap'
3+
title: 'avgMap'
4+
description: 'Example of using the avgMap combinator'
5+
keywords: ['avg', 'map', 'combinator', 'examples', 'avgMap']
6+
sidebar_label: 'avgMap'
7+
---
8+
9+
# avgMap {#avgmap}
10+
11+
## Description {#description}
12+
13+
The [`Map`](/sql-reference/aggregate-functions/combinators#-map) combinator can be applied to the [`avg`](/sql-reference/aggregate-functions/reference/avg)
14+
function to calculate the arithmetic mean of values in a Map according to each key, using the `avgMap`
15+
aggregate combinator function.
16+
17+
## Example Usage {#example-usage}
18+
19+
In this example, we'll create a table that stores status codes and their counts for different timeslots,
20+
where each row contains a Map of status codes to their corresponding counts. We'll use
21+
`avgMap` to calculate the average count for each status code within each timeslot.
22+
23+
```sql title="Query"
24+
CREATE TABLE metrics(
25+
date Date,
26+
timeslot DateTime,
27+
status Map(String, UInt64)
28+
) ENGINE = Log;
29+
30+
INSERT INTO metrics VALUES
31+
('2000-01-01', '2000-01-01 00:00:00', (['a', 'b', 'c'], [15, 25, 35])),
32+
('2000-01-01', '2000-01-01 00:00:00', (['c', 'd', 'e'], [45, 55, 65])),
33+
('2000-01-01', '2000-01-01 00:01:00', (['d', 'e', 'f'], [75, 85, 95])),
34+
('2000-01-01', '2000-01-01 00:01:00', (['f', 'g', 'g'], [105, 115, 125]));
35+
36+
SELECT
37+
timeslot,
38+
avgMap(status),
39+
FROM metrics
40+
GROUP BY timeslot;
41+
```
42+
43+
The `avgMap` function will calculate the average count for each status code within each timeslot. For example:
44+
- In timeslot '2000-01-01 00:00:00':
45+
- Status 'a': 15
46+
- Status 'b': 25
47+
- Status 'c': (35 + 45) / 2 = 40
48+
- Status 'd': 55
49+
- Status 'e': 65
50+
- In timeslot '2000-01-01 00:01:00':
51+
- Status 'd': 75
52+
- Status 'e': 85
53+
- Status 'f': (95 + 105) / 2 = 100
54+
- Status 'g': (115 + 125) / 2 = 120
55+
56+
```response title="Response"
57+
┌────────────timeslot─┬─avgMap(status)───────────────────────┐
58+
1. │ 2000-01-01 00:01:00 │ {'d':75,'e':85,'f':100,'g':120} │
59+
2. │ 2000-01-01 00:00:00 │ {'a':15,'b':25,'c':40,'d':55,'e':65} │
60+
└─────────────────────┴──────────────────────────────────────┘
61+
```
62+
63+
## See also {#see-also}
64+
- [`avg`](/sql-reference/aggregate-functions/reference/avg)
65+
- [`Map combinator`](/sql-reference/aggregate-functions/combinators#-map)
Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
1+
---
2+
slug: '/examples/aggregate-function-combinators/avgMerge'
3+
title: 'avgMerge'
4+
description: 'Example of using the avgMerge combinator'
5+
keywords: ['avg', 'merge', 'combinator', 'examples', 'avgMerge']
6+
sidebar_label: 'avgMerge'
7+
---
8+
9+
# avgMerge {#avgMerge}
10+
11+
## Description {#description}
12+
13+
The [`Merge`](/sql-reference/aggregate-functions/combinators#-state) combinator
14+
can be applied to the [`avg`](/sql-reference/aggregate-functions/reference/avg)
15+
function to produce a final result by combining partial aggregate states.
16+
17+
## Example Usage {#example-usage}
18+
19+
The `Merge` combinator is closely related to the `State` combinator. Refer to
20+
["avgState example usage"](/examples/aggregate-function-combinators/avgState/#example-usage)
21+
for an example of both `avgMerge` and `avgState`.
22+
23+
## See also {#see-also}
24+
- [`avg`](/sql-reference/aggregate-functions/reference/avg)
25+
- [`Merge`](/sql-reference/aggregate-functions/combinators#-merge)
26+
- [`MergeState`](/sql-reference/aggregate-functions/combinators#-mergestate)

0 commit comments

Comments
 (0)