Skip to content

Commit e74ae7d

Browse files
authored
[Docs]: Added SQL example for all window functions (#16074)
* update window function * pretier fix * Update window_functions.md
1 parent 3e30f77 commit e74ae7d

File tree

1 file changed

+201
-0
lines changed

1 file changed

+201
-0
lines changed

docs/source/user-guide/sql/window_functions.md

Lines changed: 201 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -193,6 +193,29 @@ Returns the rank of the current row without gaps. This function ranks rows in a
193193
dense_rank()
194194
```
195195

196+
#### Example
197+
198+
```sql
199+
--Example usage of the dense_rank window function:
200+
SELECT department,
201+
salary,
202+
dense_rank() OVER (PARTITION BY department ORDER BY salary DESC) AS dense_rank
203+
FROM employees;
204+
```
205+
206+
```sql
207+
+-------------+--------+------------+
208+
| department | salary | dense_rank |
209+
+-------------+--------+------------+
210+
| Sales | 70000 | 1 |
211+
| Sales | 50000 | 2 |
212+
| Sales | 50000 | 2 |
213+
| Sales | 30000 | 3 |
214+
| Engineering | 90000 | 1 |
215+
| Engineering | 80000 | 2 |
216+
+-------------+--------+------------+
217+
```
218+
196219
### `ntile`
197220

198221
Integer ranging from 1 to the argument value, dividing the partition as equally as possible
@@ -205,6 +228,31 @@ ntile(expression)
205228

206229
- **expression**: An integer describing the number groups the partition should be split into
207230

231+
#### Exmaple
232+
233+
```sql
234+
--Example usage of the ntile window function:
235+
SELECT employee_id,
236+
salary,
237+
ntile(4) OVER (ORDER BY salary DESC) AS quartile
238+
FROM employees;
239+
```
240+
241+
```sql
242+
+-------------+--------+----------+
243+
| employee_id | salary | quartile |
244+
+-------------+--------+----------+
245+
| 1 | 90000 | 1 |
246+
| 2 | 85000 | 1 |
247+
| 3 | 80000 | 2 |
248+
| 4 | 70000 | 2 |
249+
| 5 | 60000 | 3 |
250+
| 6 | 50000 | 3 |
251+
| 7 | 40000 | 4 |
252+
| 8 | 30000 | 4 |
253+
+-------------+--------+----------+
254+
```
255+
208256
### `percent_rank`
209257

210258
Returns the percentage rank of the current row within its partition. The value ranges from 0 to 1 and is computed as `(rank - 1) / (total_rows - 1)`.
@@ -213,6 +261,26 @@ Returns the percentage rank of the current row within its partition. The value r
213261
percent_rank()
214262
```
215263

264+
#### Example
265+
266+
```sql
267+
--Example usage of the percent_rank window function:
268+
SELECT employee_id,
269+
salary,
270+
percent_rank() OVER (ORDER BY salary) AS percent_rank
271+
FROM employees;
272+
```
273+
274+
```sql
275+
+-------------+--------+---------------+
276+
| employee_id | salary | percent_rank |
277+
+-------------+--------+---------------+
278+
| 1 | 30000 | 0.00 |
279+
| 2 | 50000 | 0.50 |
280+
| 3 | 70000 | 1.00 |
281+
+-------------+--------+---------------+
282+
```
283+
216284
### `rank`
217285

218286
Returns the rank of the current row within its partition, allowing gaps between ranks. This function provides a ranking similar to `row_number`, but skips ranks for identical values.
@@ -221,6 +289,29 @@ Returns the rank of the current row within its partition, allowing gaps between
221289
rank()
222290
```
223291

292+
#### Example
293+
294+
```sql
295+
--Example usage of the rank window function:
296+
SELECT department,
297+
salary,
298+
rank() OVER (PARTITION BY department ORDER BY salary DESC) AS rank
299+
FROM employees;
300+
```
301+
302+
```sql
303+
+-------------+--------+------+
304+
| department | salary | rank |
305+
+-------------+--------+------+
306+
| Sales | 70000 | 1 |
307+
| Sales | 50000 | 2 |
308+
| Sales | 50000 | 2 |
309+
| Sales | 30000 | 4 |
310+
| Engineering | 90000 | 1 |
311+
| Engineering | 80000 | 2 |
312+
+-------------+--------+------+
313+
```
314+
224315
### `row_number`
225316

226317
Number of the current row within its partition, counting from 1.
@@ -229,6 +320,29 @@ Number of the current row within its partition, counting from 1.
229320
row_number()
230321
```
231322

323+
#### Example
324+
325+
```sql
326+
--Example usage of the row_number window function:
327+
SELECT department,
328+
salary,
329+
row_number() OVER (PARTITION BY department ORDER BY salary DESC) AS row_num
330+
FROM employees;
331+
```
332+
333+
```sql
334+
+-------------+--------+---------+
335+
| department | salary | row_num |
336+
+-------------+--------+---------+
337+
| Sales | 70000 | 1 |
338+
| Sales | 50000 | 2 |
339+
| Sales | 50000 | 3 |
340+
| Sales | 30000 | 4 |
341+
| Engineering | 90000 | 1 |
342+
| Engineering | 80000 | 2 |
343+
+-------------+--------+---------+
344+
```
345+
232346
## Analytical Functions
233347

234348
- [first_value](#first_value)
@@ -249,6 +363,29 @@ first_value(expression)
249363

250364
- **expression**: Expression to operate on
251365

366+
#### Example
367+
368+
```sql
369+
--Example usage of the first_value window function:
370+
SELECT department,
371+
employee_id,
372+
salary,
373+
first_value(salary) OVER (PARTITION BY department ORDER BY salary DESC) AS top_salary
374+
FROM employees;
375+
```
376+
377+
```sql
378+
+-------------+-------------+--------+------------+
379+
| department | employee_id | salary | top_salary |
380+
+-------------+-------------+--------+------------+
381+
| Sales | 1 | 70000 | 70000 |
382+
| Sales | 2 | 50000 | 70000 |
383+
| Sales | 3 | 30000 | 70000 |
384+
| Engineering | 4 | 90000 | 90000 |
385+
| Engineering | 5 | 80000 | 90000 |
386+
+-------------+-------------+--------+------------+
387+
```
388+
252389
### `lag`
253390

254391
Returns value evaluated at the row that is offset rows before the current row within the partition; if there is no such row, instead return default (which must be of the same type as value).
@@ -263,6 +400,27 @@ lag(expression, offset, default)
263400
- **offset**: Integer. Specifies how many rows back the value of expression should be retrieved. Defaults to 1.
264401
- **default**: The default value if the offset is not within the partition. Must be of the same type as expression.
265402

403+
#### Example
404+
405+
```sql
406+
--Example usage of the lag window function:
407+
SELECT employee_id,
408+
salary,
409+
lag(salary, 1, 0) OVER (ORDER BY employee_id) AS prev_salary
410+
FROM employees;
411+
```
412+
413+
```sql
414+
+-------------+--------+-------------+
415+
| employee_id | salary | prev_salary |
416+
+-------------+--------+-------------+
417+
| 1 | 30000 | 0 |
418+
| 2 | 50000 | 30000 |
419+
| 3 | 70000 | 50000 |
420+
| 4 | 60000 | 70000 |
421+
+-------------+--------+-------------+
422+
```
423+
266424
### `last_value`
267425

268426
Returns value evaluated at the row that is the last row of the window frame.
@@ -275,6 +433,27 @@ last_value(expression)
275433

276434
- **expression**: Expression to operate on
277435

436+
```sql
437+
-- SQL example of last_value:
438+
SELECT department,
439+
employee_id,
440+
salary,
441+
last_value(salary) OVER (PARTITION BY department ORDER BY salary) AS running_last_salary
442+
FROM employees;
443+
```
444+
445+
```sql
446+
+-------------+-------------+--------+---------------------+
447+
| department | employee_id | salary | running_last_salary |
448+
+-------------+-------------+--------+---------------------+
449+
| Sales | 1 | 30000 | 30000 |
450+
| Sales | 2 | 50000 | 50000 |
451+
| Sales | 3 | 70000 | 70000 |
452+
| Engineering | 4 | 40000 | 40000 |
453+
| Engineering | 5 | 60000 | 60000 |
454+
+-------------+-------------+--------+---------------------+
455+
```
456+
278457
### `lead`
279458

280459
Returns value evaluated at the row that is offset rows after the current row within the partition; if there is no such row, instead return default (which must be of the same type as value).
@@ -289,6 +468,28 @@ lead(expression, offset, default)
289468
- **offset**: Integer. Specifies how many rows forward the value of expression should be retrieved. Defaults to 1.
290469
- **default**: The default value if the offset is not within the partition. Must be of the same type as expression.
291470

471+
```sql
472+
-- Example usage of lead() :
473+
SELECT
474+
employee_id,
475+
department,
476+
salary,
477+
lead(salary, 1, 0) OVER (PARTITION BY department ORDER BY salary) AS next_salary
478+
FROM employees;
479+
```
480+
481+
```sql
482+
+-------------+-------------+--------+--------------+
483+
| employee_id | department | salary | next_salary |
484+
+-------------+-------------+--------+--------------+
485+
| 1 | Sales | 30000 | 50000 |
486+
| 2 | Sales | 50000 | 70000 |
487+
| 3 | Sales | 70000 | 0 |
488+
| 4 | Engineering | 40000 | 60000 |
489+
| 5 | Engineering | 60000 | 0 |
490+
+-------------+-------------+--------+--------------+
491+
```
492+
292493
### `nth_value`
293494

294495
Returns the value evaluated at the nth row of the window frame (counting from 1). Returns NULL if no such row exists.

0 commit comments

Comments
 (0)