AVG
Calculate the average value from a set of numbers.
NULL values are ignored. If no values can be averaged, this function returns NULL.
May be used as a window function and with the frame clause.
Syntax
Aggregate Function
AVG ( [DISTINCT] expression )
Window Function & Window Frame Clause
AVG( [ DISTINCT ] ( ) OVER ( [ PARTITION BY (col | expr), ...] [ORDER BY (col | expr), ...] [ <window_frame> ] )
Arguments
DISTINCT: optional keyword. If present, will average the unique values.
expression: any numerical expression. This may be a column name, the result of another function, or a math operation
Return Type
A double if the input type is double, otherwise decimal.
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 AVG(yearly_total) FROM player_scores; **** +-------------------+ | AVG(yearly_total) | +-------------------+ | 314.914286 | +-------------------+
SELECT AVG(yearly_total), (player_name) FROM player_scores GROUP BY player_name; **** +-------------------+-------------+ | AVG(yearly_total) | player_name | +-------------------+-------------+ | 327.300000 | June | | 348.500000 | Jack | | 369.100000 | Eve | | 202.500000 | Steve | | 378.300000 | Martin | | 271.600000 | Jim | | 307.100000 | Shelia | +-------------------+-------------+
Window Function
SELECT player_id, avg(1st_qtr_score), avg(2nd_qtr_score), avg(3rd_qtr_score), avg(4th_qtr_score) OVER (PARTITION BY player_id) FROM player_scores GROUP BY player_id ORDER BY player_id; **** +-----------+--------------------+--------------------+--------------------+--------------------------+ | player_id | avg(1st_qtr_score) | avg(2nd_qtr_score) | avg(3rd_qtr_score) | avg(4th_qtr_score) OVER | | | | | | (partition by player_id) | +-----------+--------------------+--------------------+--------------------+--------------------------+ | 119 | 22.500000 | 72.000000 | 63.000000 | 45.000000 | | 189 | 91.500000 | 88.100000 | 95.000000 | 94.500000 | | 338 | 75.600000 | 72.000000 | 81.100000 | 78.400000 | | 432 | 90.100000 | 78.000000 | 88.200000 | 92.200000 | | 521 | 81.000000 | 87.300000 | 76.800000 | 82.200000 | | 674 | 98.800000 | 95.100000 | 88.000000 | 96.400000 | | 779 | 75.000000 | 68.900000 | 55.700000 | 72.000000 | +-----------+--------------------+--------------------+--------------------+--------------------------+
CREATE TABLE avg_tick_table(TIMESTAMP DATETIME(6), symbol VARCHAR(5), comp_name VARCHAR (30), price NUMERIC(18,4)); INSERT INTO avg_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, AVG(price) OVER (PARTITION BY symbol) FROM avg_tick_table GROUP BY TIMESTAMP; **** +----------------------------+--------+----------+---------------------------------------+ | TIMESTAMP | symbol | price | AVG(price) OVER (PARTITION BY symbol) | +----------------------------+--------+----------+---------------------------------------+ | 2022-11-18 10:55:50.000000 | AME | 208.0000 | 209.00000000 | | 2022-11-18 10:55:52.000000 | AME | 210.0000 | 209.00000000 | | 2022-11-18 10:55:57.000000 | OCO | 21.0000 | 22.50000000 | | 2022-11-18 10:56:00.000000 | OCO | 23.0000 | 22.50000000 | | 2022-11-18 10:56:03.000000 | OCO | 24.0000 | 22.50000000 | | 2022-11-18 10:55:55.000000 | OCO | 22.0000 | 22.50000000 | | 2022-11-18 10:55:36.000000 | STC | 100.0000 | 102.00000000 | | 2022-11-18 10:55:48.000000 | STC | 101.0000 | 102.00000000 | | 2022-11-18 10:55:42.000000 | STC | 105.0000 | 102.00000000 | | 2022-11-18 10:55:37.000000 | STC | 102.0000 | 102.00000000 | +----------------------------+--------+----------+---------------------------------------+
Window Frame Clause
CREATE TABLE avg_table(col_a INT, col_b DECIMAL(4,2), col_c DECIMAL(4,2), col_d VARCHAR(15), col_e INT); INSERT INTO avg_table VALUES(1, 1.1, 11.17, 'one', 47), (2, 2.2, 22.21, 'two', NULL), (NULL, 3.3, 33.32, 'three', 892), (4, 4.4, 44.43, 'four', NULL), (5, 5.5, 55.54, 'five', 1102), (6, NULL, 66.65, 'six', NULL);
SELECT col_a, col_b, col_c, col_d, col_e, AVG(col_e) OVER (PARTITION BY col_a ORDER BY col_b rows between UNBOUNDED PRECEDING and CURRENT ROW) avg_col_e_rows_pre FROM avg_table ORDER BY col_a; **** +-------+-------+-------+-------+-------+--------------------+ | col_a | col_b | col_c | col_d | col_e | avg_col_e_rows_pre | +-------+-------+-------+-------+-------+--------------------+ | NULL | 3.30 | 33.32 | three | 892 | 892.0000 | | 1 | 1.10 | 11.17 | one | 47 | 47.0000 | | 2 | 2.20 | 22.21 | two | NULL | NULL | | 4 | 4.40 | 44.43 | four | NULL | NULL | | 5 | 5.50 | 55.54 | five | 1102 | 1102.0000 | | 6 | NULL | 66.65 | six | NULL | NULL | +-------+-------+-------+-------+-------+--------------------+
SELECT TIMESTAMP, symbol, price, AVG(price) OVER (PARTITION BY symbol ROWS between 1 PRECEDING and CURRENT ROW) AS AVG_2, AVG(price) OVER (ORDER BY TIMESTAMP ROWS between 2 PRECEDING and CURRENT ROW) AS AVG_3 FROM avg_tick_table; **** +----------------------------+--------+----------+--------------+--------------+ | TIMESTAMP | symbol | price | AVG_2 | AVG_3 | +----------------------------+--------+----------+--------------+--------------+ | 2022-11-18 10:55:36.000000 | STC | 100.0000 | 100.50000000 | 100.00000000 | | 2022-11-18 10:55:37.000000 | STC | 102.0000 | 103.50000000 | 101.00000000 | | 2022-11-18 10:55:42.000000 | STC | 105.0000 | 105.00000000 | 102.33333333 | | 2022-11-18 10:55:42.000000 | AME | 198.0000 | 204.50000000 | 135.00000000 | | 2022-11-18 10:55:48.000000 | STC | 101.0000 | 101.50000000 | 134.66666667 | | 2022-11-18 10:55:50.000000 | AME | 208.0000 | 203.00000000 | 169.00000000 | | 2022-11-18 10:55:52.000000 | OCO | 21.0000 | 22.00000000 | 110.00000000 | | 2022-11-18 10:55:52.000000 | AME | 210.0000 | 210.00000000 | 146.33333333 | | 2022-11-18 10:55:55.000000 | OCO | 22.0000 | 23.00000000 | 84.33333333 | | 2022-11-18 10:55:55.000000 | AME | 211.0000 | 210.50000000 | 147.66666667 | | 2022-11-18 10:55:57.000000 | OCO | 21.0000 | 21.00000000 | 84.66666667 | | 2022-11-18 10:56:00.000000 | OCO | 23.0000 | 22.50000000 | 85.00000000 | | 2022-11-18 10:56:03.000000 | STC | 99.0000 | 99.50000000 | 47.66666667 | | 2022-11-18 10:56:03.000000 | OCO | 24.0000 | 24.00000000 | 48.66666667 | +----------------------------+--------+----------+--------------+--------------+