MAX

Returns the highest value observed in all rows in an aggregation.

Highest is determined by the collation rules of the data passed in.

May be used as a window function and with the frame clause.

Note

This aggregate function is not to be confused with GREATEST, which is a non-aggregate function returning the highest value in its list of arguments.

Syntax

Aggregate Function

MAX (expression)

Window Function & Window Frame Clause

MAX(col | expr) [ OVER ( [PARTITION BY (col | expr) ] [ORDER BY (col | expr) [<window_frame>] ] ) ]

Arguments

  • expression: any expression. This may be a column name, the result of another function, or a math operation.

Return Type

The highest value, in the type of the input.

Examples

CREATE TABLE player_scores(player_name VARCHAR(50), player_id VARCHAR(10), 
    1st_qtr_score DECIMAL(5,2), 2nd_qtr_score DECIMAL(5,2), 
    3rd_qtr_score DECIMAL(5,2), 4th_qtr_score DECIMAL(5,2), 
    yearly_total AS 1st_qtr_score + 2nd_qtr_score + 3rd_qtr_score + 4th_qtr_score PERSISTED DECIMAL(5,2));
INSERT INTO player_scores VALUES
    ('Steve', '119','22.50','72.00', '63.00', '45.00'),
    ('Jack', '432', '90.10', '78.00','88.20', '92.20'),
    ('Jim', '779','75.00', '68.90','55.70', '72.00'), 
    ('Eve', '189','91.50', '88.10', '95.00', '94.50'),
    ('Shelia','338', '75.60', '72.00', '81.10', '78.40'),
    ('June', '521', '81.00', '87.30','76.80','82.20'),
    ('Martin', '674','98.80', '95.10', '88.00', '96.40');

Aggregate Function

SELECT MAX(player_name) FROM player_scores;
+------------------+
| MAX(player_name) |
+------------------+
| Steve            |
+------------------+
SELECT MAX(player_id) FROM player_scores;
+----------------+
| MAX(player_id) |
+----------------+
| 779            |
+----------------+

Window Function

SELECT player_name, 1st_qtr_score, 2nd_qtr_score, MAX(2nd_qtr_score) 
OVER (partition by 1st_qtr_score) FROM player_scores ORDER BY 1st_qtr_score, 2nd_qtr_score;
+-------------+---------------+---------------+-----------------------------------+
| player_name | 1st_qtr_score | 2nd_qtr_score | MAX(2nd_qtr_score)                |
|             |               |               | OVER (partition by 1st_qtr_score) |
+-------------+---------------+---------------+-----------------------------------+
| Steve       |         22.50 |         72.00 |                             72.00 |
| Jim         |         75.00 |         68.90 |                             68.90 |
| Shelia      |         75.60 |         72.00 |                             72.00 |
| June        |         81.00 |         87.30 |                             87.30 |
| Jack        |         90.10 |         78.00 |                             78.00 |
| Eve         |         91.50 |         88.10 |                             88.10 |
| Martin      |         98.80 |         95.10 |                             95.10 |
+-------------+---------------+---------------+-----------------------------------+
CREATE TABLE tick_table(TIMESTAMP DATETIME(6), symbol VARCHAR(5), comp_name VARCHAR (30), price NUMERIC(18,4));
INSERT INTO tick_table VALUES('2022-11-18 10:55:36.000000','STC','SomeTechCo', 100.00),
('2022-11-18 10:55:37.000000','STC','SomeTechCo', 102.00),
('2022-11-18 10:55:42.000000', 'STC', 'SomeTechCo', 105.00),
('2022-11-18 10:55:48.000000', 'STC', 'SomeTechCo', 101.00),
('2022-11-18 10:56:03.000000', 'STC', 'SomeTechCo', 99.00),
('2022-11-18 10:55:42.000000', 'AME', 'ACME', 198.00),
('2022-11-18 10:55:50.000000', 'AME', 'ACME', 208.00),
('2022-11-18 10:55:52.000000', 'AME', 'ACME', 210.00),
('2022-11-18 10:55:55.000000', 'AME', 'ACME', 211.00),
('2022-11-18 10:55:52.000000', 'OCO', 'OnCallCo', 21.00),
('2022-11-18 10:55:55.000000', 'OCO', 'OnCallCo', 22.00),
('2022-11-18 10:55:57.000000', 'OCO', 'OnCallCo', 21.00),
('2022-11-18 10:56:00.000000', 'OCO', 'OnCallCo', 23.00),
('2022-11-18 10:56:03.000000', 'OCO', 'OnCallCo', 24.00);
SELECT TIMESTAMP, symbol, price, MAX(price) OVER (PARTITION BY symbol)
FROM tick_table GROUP BY TIMESTAMP;
+----------------------------+--------+----------+---------------------------------------+
| TIMESTAMP                  | symbol | price    | MAX(price) OVER (PARTITION BY symbol) |
+----------------------------+--------+----------+---------------------------------------+
| 2022-11-18 10:55:50.000000 | AME    | 208.0000 |                              208.0000 |
| 2022-11-18 10:55:55.000000 | OCO    |  22.0000 |                               23.0000 |
| 2022-11-18 10:55:52.000000 | OCO    |  21.0000 |                               23.0000 |
| 2022-11-18 10:56:00.000000 | OCO    |  23.0000 |                               23.0000 |
| 2022-11-18 10:55:57.000000 | OCO    |  21.0000 |                               23.0000 |
| 2022-11-18 10:55:42.000000 | STC    | 105.0000 |                              105.0000 |
| 2022-11-18 10:55:37.000000 | STC    | 102.0000 |                              105.0000 |
| 2022-11-18 10:55:48.000000 | STC    | 101.0000 |                              105.0000 |
| 2022-11-18 10:55:36.000000 | STC    | 100.0000 |                              105.0000 |
| 2022-11-18 10:56:03.000000 | STC    |  99.0000 |                              105.0000 |
+----------------------------+--------+----------+---------------------------------------+

Window Frame Clause

SELECT col_a, col_b, col_c, col_d, col_e,
max(col_e) OVER (PARTITION BY col_a ORDER BY col_b rows between UNBOUNDED PRECEDING and CURRENT ROW) max_col_e_rows_pre
FROM avg_table
ORDER BY col_a;
+-------+-------+-------+-------+-------+--------------------+
| col_a | col_b | col_c | col_d | col_e | max_col_e_rows_pre |
+-------+-------+-------+-------+-------+--------------------+
|  NULL |  3.30 | 33.32 | three |   892 |                892 |
|     1 |  1.10 | 11.17 | one   |    47 |                 47 |
|     2 |  2.20 | 22.21 | two   |  NULL |               NULL |
|     4 |  4.40 | 44.43 | four  |  NULL |               NULL |
|     5 |  5.50 | 55.54 | five  |  1102 |               1102 |
|     6 |  NULL | 66.65 | six   |  NULL |               NULL |
+-------+-------+-------+-------+-------+--------------------+

Last modified: April 4, 2023

Was this article helpful?