You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Copy file name to clipboardExpand all lines: docs/source/user-guide/sql/window_functions.md
+201Lines changed: 201 additions & 0 deletions
Original file line number
Diff line number
Diff line change
@@ -193,6 +193,29 @@ Returns the rank of the current row without gaps. This function ranks rows in a
193
193
dense_rank()
194
194
```
195
195
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
+
196
219
### `ntile`
197
220
198
221
Integer ranging from 1 to the argument value, dividing the partition as equally as possible
@@ -205,6 +228,31 @@ ntile(expression)
205
228
206
229
-**expression**: An integer describing the number groups the partition should be split into
207
230
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
+
208
256
### `percent_rank`
209
257
210
258
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
213
261
percent_rank()
214
262
```
215
263
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
+
216
284
### `rank`
217
285
218
286
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
221
289
rank()
222
290
```
223
291
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
+
224
315
### `row_number`
225
316
226
317
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.
229
320
row_number()
230
321
```
231
322
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
+
232
346
## Analytical Functions
233
347
234
348
-[first_value](#first_value)
@@ -249,6 +363,29 @@ first_value(expression)
249
363
250
364
-**expression**: Expression to operate on
251
365
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
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).
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).
0 commit comments