Small. Fast. Reliable.
Choose any three.
Built-in Aggregate Functions

1. Syntax

aggregate-function-invocation:

aggregate-func ( DISTINCT expr ) filter-clause , *

expr:

filter-clause:

The aggregate functions shown below are available by default. Additional aggregate functions written in C may be added using the sqlite3_create_function() API.

R-00466-56349:[In any aggregate function that takes a single argument, that argument can be preceded by the keyword DISTINCT. ] R-00171-59428:[In such cases, duplicate elements are filtered before being passed into the aggregate function. ] R-31453-41389:[For example, the function "count(distinct X)" will return the number of distinct values of column X instead of the total number of non-null values in column X. ]

If a FILTER clause is provided, then only rows for which the expr is true are included in the aggregate.

2. List of built-in aggregate functions

3. Descriptions of built-in aggregate functions

avg(X)

R-20409-33051:[The avg() function returns the average value of all non-NULL X within a group. ] R-29052-00975:[String and BLOB values that do not look like numbers are interpreted as 0. ] R-17177-10067:[The result of avg() is always a floating point value whenever there is at least one non-NULL input even if all inputs are integers. ] R-40597-22164:[The result of avg() is NULL if and only if there are no non-NULL inputs. ]

count(X)
count(*)

R-34280-42283:[The count(X) function returns a count of the number of times that X is not NULL in a group. ] R-13776-21310:[The count(*) function (with no arguments) returns the total number of rows in the group. ]

group_concat(X)
group_concat(X,Y)

R-56088-25150:[The group_concat() function returns a string which is the concatenation of all non-NULL values of X. ] R-08600-21007:[If parameter Y is present then it is used as the separator between instances of X. ] R-39910-14723:[A comma (",") is used as the separator if Y is omitted. ] The order of the concatenated elements is arbitrary.

max(X)

R-52585-35928:[The max() aggregate function returns the maximum value of all values in the group. ] R-13053-11096:[The maximum value is the value that would be returned last in an ORDER BY on the same column. ] R-50775-16353:[Aggregate max() returns NULL if and only if there are no non-NULL values in the group. ]

min(X)

R-16028-39081:[The min() aggregate function returns the minimum non-NULL value of all values in the group. ] R-30311-39793:[The minimum value is the first non-NULL value that would appear in an ORDER BY of the column. ] R-10396-30188:[Aggregate min() returns NULL if and only if there are no non-NULL values in the group. ]

sum(X)
total(X)

R-24943-34514:[The sum() and total() aggregate functions return the sum of all non-NULL values in the group. ] R-44223-43966:[If there are no non-NULL input rows then sum() returns NULL but total() returns 0. ] 0. NULL is not normally a helpful result for the sum of no rows but the SQL standard requires it and most other SQL database engines implement sum() that way so SQLite does it in the same way in order to be compatible. The non-standard total() function is provided as a convenient way to work around this design problem in the SQL language.

R-07734-01023:[The result of total() is always a floating point value. ] R-19660-56479:[The result of sum() is an integer value if all non-NULL inputs are integers. ] R-33611-59266:[If any input to sum() is neither an integer nor a NULL, then sum() returns a floating point value which is an approximation of the mathematical sum. ]

R-08904-24719:[Sum() will throw an "integer overflow" exception if all inputs are integers or NULL and an integer overflow occurs at any point during the computation. ] R-19553-64528:[Total() never throws an integer overflow. ]