MEDIAN
On this page
It is an aggregate function that returns the median of an expression (middle value in a sorted data set), which separates the higher half in a distribution from the lower half.
May be used as a window function.
Syntax
Aggregate Function
MEDIAN ( expression )
Window Function
MEDIAN(col | expr ) OVER ( [ PARTITION BY (col | expr ) ] )
Arguments
- 
        
expression: Any numeric expression.
 
Return Type
Numeric value.
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 player_name, 1st_qtr_score, 2nd_qtr_score, median(2nd_qtr_score) FROM player_scores GROUP BY player_name ORDER BY player_name;
+-------------+---------------+---------------+-----------------------+
| player_name | 1st_qtr_score | 2nd_qtr_score | median(2nd_qtr_score) |
+-------------+---------------+---------------+-----------------------+
| Eve         |         91.50 |         88.10 |             88.100000 |
| Jack        |         90.10 |         78.00 |             78.000000 |
| Jim         |         75.00 |         68.90 |             68.900000 |
| June        |         81.00 |         87.30 |             87.300000 |
| Martin      |         98.80 |         95.10 |             95.100000 |
| Shelia      |         75.60 |         72.00 |             72.000000 |
| Steve       |         22.50 |         72.00 |             72.000000 |
+-------------+---------------+---------------+-----------------------+Window Function
SELECT player_name, 1st_qtr_score, 2nd_qtr_score, MEDIAN(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 | MEDIAN(2nd_qtr_score)             |
|             |               |               | OVER (PARTITION BY 1st_qtr_score) |
+-------------+---------------+---------------+-----------------------------------+
| Steve       |         22.50 |         72.00 |                         72.000000 |
| Jim         |         75.00 |         68.90 |                         68.900000 |
| Shelia      |         75.60 |         72.00 |                         72.000000 |
| June        |         81.00 |         87.30 |                         87.300000 |
| Jack        |         90.10 |         78.00 |                         78.000000 |
| Eve         |         91.50 |         88.10 |                         88.100000 |
| Martin      |         98.80 |         95.10 |                         95.100000 |
+-------------+---------------+---------------+----------------------------------------------------------+Last modified: February 23, 2023