329 lines
14 KiB
HTML
329 lines
14 KiB
HTML
<!DOCTYPE html>
|
|
<html><head>
|
|
<meta name="viewport" content="width=device-width, initial-scale=1.0">
|
|
<meta http-equiv="content-type" content="text/html; charset=UTF-8">
|
|
<link href="sqlite.css" rel="stylesheet">
|
|
<title>Built-in Aggregate Functions</title>
|
|
<!-- path= -->
|
|
</head>
|
|
<body>
|
|
<div class=nosearch>
|
|
<a href="index.html">
|
|
<img class="logo" src="images/sqlite370_banner.gif" alt="SQLite" border="0">
|
|
</a>
|
|
<div><!-- IE hack to prevent disappearing logo --></div>
|
|
<div class="tagline desktoponly">
|
|
Small. Fast. Reliable.<br>Choose any three.
|
|
</div>
|
|
<div class="menu mainmenu">
|
|
<ul>
|
|
<li><a href="index.html">Home</a>
|
|
<li class='mobileonly'><a href="javascript:void(0)" onclick='toggle_div("submenu")'>Menu</a>
|
|
<li class='wideonly'><a href='about.html'>About</a>
|
|
<li class='desktoponly'><a href="docs.html">Documentation</a>
|
|
<li class='desktoponly'><a href="download.html">Download</a>
|
|
<li class='wideonly'><a href='copyright.html'>License</a>
|
|
<li class='desktoponly'><a href="support.html">Support</a>
|
|
<li class='desktoponly'><a href="prosupport.html">Purchase</a>
|
|
<li class='search' id='search_menubutton'>
|
|
<a href="javascript:void(0)" onclick='toggle_search()'>Search</a>
|
|
</ul>
|
|
</div>
|
|
<div class="menu submenu" id="submenu">
|
|
<ul>
|
|
<li><a href='about.html'>About</a>
|
|
<li><a href='docs.html'>Documentation</a>
|
|
<li><a href='download.html'>Download</a>
|
|
<li><a href='support.html'>Support</a>
|
|
<li><a href='prosupport.html'>Purchase</a>
|
|
</ul>
|
|
</div>
|
|
<div class="searchmenu" id="searchmenu">
|
|
<form method="GET" action="search">
|
|
<select name="s" id="searchtype">
|
|
<option value="d">Search Documentation</option>
|
|
<option value="c">Search Changelog</option>
|
|
</select>
|
|
<input type="text" name="q" id="searchbox" value="">
|
|
<input type="submit" value="Go">
|
|
</form>
|
|
</div>
|
|
</div>
|
|
<script>
|
|
function toggle_div(nm) {
|
|
var w = document.getElementById(nm);
|
|
if( w.style.display=="block" ){
|
|
w.style.display = "none";
|
|
}else{
|
|
w.style.display = "block";
|
|
}
|
|
}
|
|
function toggle_search() {
|
|
var w = document.getElementById("searchmenu");
|
|
if( w.style.display=="block" ){
|
|
w.style.display = "none";
|
|
} else {
|
|
w.style.display = "block";
|
|
setTimeout(function(){
|
|
document.getElementById("searchbox").focus()
|
|
}, 30);
|
|
}
|
|
}
|
|
function div_off(nm){document.getElementById(nm).style.display="none";}
|
|
window.onbeforeunload = function(e){div_off("submenu");}
|
|
/* Disable the Search feature if we are not operating from CGI, since */
|
|
/* Search is accomplished using CGI and will not work without it. */
|
|
if( !location.origin || !location.origin.match || !location.origin.match(/http/) ){
|
|
document.getElementById("search_menubutton").style.display = "none";
|
|
}
|
|
/* Used by the Hide/Show button beside syntax diagrams, to toggle the */
|
|
function hideorshow(btn,obj){
|
|
var x = document.getElementById(obj);
|
|
var b = document.getElementById(btn);
|
|
if( x.style.display!='none' ){
|
|
x.style.display = 'none';
|
|
b.innerHTML='show';
|
|
}else{
|
|
x.style.display = '';
|
|
b.innerHTML='hide';
|
|
}
|
|
return false;
|
|
}
|
|
</script>
|
|
</div>
|
|
<div class=fancy>
|
|
<div class=nosearch>
|
|
<div class="fancy_title">
|
|
Built-in Aggregate Functions
|
|
</div>
|
|
</div>
|
|
|
|
|
|
|
|
|
|
|
|
<h1 id="syntax"><span>1. </span>Syntax</h1>
|
|
<p><b><a href="syntax/aggregate-function-invocation.html">aggregate-function-invocation:</a></b>
|
|
<button id='x1181' onclick='hideorshow("x1181","x1182")'>hide</button></p>
|
|
<div id='x1182' class='imgcontainer'>
|
|
<img alt="syntax diagram aggregate-function-invocation" src="images/syntax/aggregate-function-invocation.gif" />
|
|
<p><b><a href="syntax/expr.html">expr:</a></b>
|
|
<button id='x1183' onclick='hideorshow("x1183","x1184")'>show</button></p>
|
|
<div id='x1184' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram expr" src="images/syntax/expr.gif" />
|
|
<p><b><a href="syntax/literal-value.html">literal-value:</a></b>
|
|
<button id='x1185' onclick='hideorshow("x1185","x1186")'>show</button></p>
|
|
<div id='x1186' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram literal-value" src="images/syntax/literal-value.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/over-clause.html">over-clause:</a></b>
|
|
<button id='x1187' onclick='hideorshow("x1187","x1188")'>show</button></p>
|
|
<div id='x1188' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram over-clause" src="images/syntax/over-clause.gif" />
|
|
<p><b><a href="syntax/frame-spec.html">frame-spec:</a></b>
|
|
<button id='x1189' onclick='hideorshow("x1189","x1190")'>show</button></p>
|
|
<div id='x1190' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram frame-spec" src="images/syntax/frame-spec.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/ordering-term.html">ordering-term:</a></b>
|
|
<button id='x1191' onclick='hideorshow("x1191","x1192")'>show</button></p>
|
|
<div id='x1192' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram ordering-term" src="images/syntax/ordering-term.gif" />
|
|
</div>
|
|
</div>
|
|
<p><b><a href="syntax/raise-function.html">raise-function:</a></b>
|
|
<button id='x1193' onclick='hideorshow("x1193","x1194")'>show</button></p>
|
|
<div id='x1194' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram raise-function" src="images/syntax/raise-function.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/select-stmt.html">select-stmt:</a></b>
|
|
<button id='x1195' onclick='hideorshow("x1195","x1196")'>show</button></p>
|
|
<div id='x1196' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram select-stmt" src="images/syntax/select-stmt.gif" />
|
|
<p><b><a href="syntax/common-table-expression.html">common-table-expression:</a></b>
|
|
<button id='x1197' onclick='hideorshow("x1197","x1198")'>show</button></p>
|
|
<div id='x1198' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram common-table-expression" src="images/syntax/common-table-expression.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/compound-operator.html">compound-operator:</a></b>
|
|
<button id='x1199' onclick='hideorshow("x1199","x1200")'>show</button></p>
|
|
<div id='x1200' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram compound-operator" src="images/syntax/compound-operator.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/join-clause.html">join-clause:</a></b>
|
|
<button id='x1201' onclick='hideorshow("x1201","x1202")'>show</button></p>
|
|
<div id='x1202' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram join-clause" src="images/syntax/join-clause.gif" />
|
|
<p><b><a href="syntax/join-constraint.html">join-constraint:</a></b>
|
|
<button id='x1203' onclick='hideorshow("x1203","x1204")'>show</button></p>
|
|
<div id='x1204' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram join-constraint" src="images/syntax/join-constraint.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/join-operator.html">join-operator:</a></b>
|
|
<button id='x1205' onclick='hideorshow("x1205","x1206")'>show</button></p>
|
|
<div id='x1206' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram join-operator" src="images/syntax/join-operator.gif" />
|
|
</div>
|
|
</div>
|
|
<p><b><a href="syntax/ordering-term.html">ordering-term:</a></b>
|
|
<button id='x1207' onclick='hideorshow("x1207","x1208")'>show</button></p>
|
|
<div id='x1208' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram ordering-term" src="images/syntax/ordering-term.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/result-column.html">result-column:</a></b>
|
|
<button id='x1209' onclick='hideorshow("x1209","x1210")'>show</button></p>
|
|
<div id='x1210' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram result-column" src="images/syntax/result-column.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/table-or-subquery.html">table-or-subquery:</a></b>
|
|
<button id='x1211' onclick='hideorshow("x1211","x1212")'>show</button></p>
|
|
<div id='x1212' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram table-or-subquery" src="images/syntax/table-or-subquery.gif" />
|
|
</div>
|
|
<p><b><a href="syntax/window-defn.html">window-defn:</a></b>
|
|
<button id='x1213' onclick='hideorshow("x1213","x1214")'>show</button></p>
|
|
<div id='x1214' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram window-defn" src="images/syntax/window-defn.gif" />
|
|
<p><b><a href="syntax/frame-spec.html">frame-spec:</a></b>
|
|
<button id='x1215' onclick='hideorshow("x1215","x1216")'>show</button></p>
|
|
<div id='x1216' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram frame-spec" src="images/syntax/frame-spec.gif" />
|
|
</div>
|
|
</div>
|
|
</div>
|
|
<p><b><a href="syntax/type-name.html">type-name:</a></b>
|
|
<button id='x1217' onclick='hideorshow("x1217","x1218")'>show</button></p>
|
|
<div id='x1218' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram type-name" src="images/syntax/type-name.gif" />
|
|
<p><b><a href="syntax/signed-number.html">signed-number:</a></b>
|
|
<button id='x1219' onclick='hideorshow("x1219","x1220")'>show</button></p>
|
|
<div id='x1220' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram signed-number" src="images/syntax/signed-number.gif" />
|
|
</div>
|
|
</div>
|
|
</div>
|
|
<p><b><a href="syntax/filter-clause.html">filter-clause:</a></b>
|
|
<button id='x1221' onclick='hideorshow("x1221","x1222")'>show</button></p>
|
|
<div id='x1222' style='display:none;' class='imgcontainer'>
|
|
<img alt="syntax diagram filter-clause" src="images/syntax/filter-clause.gif" />
|
|
</div>
|
|
</div>
|
|
|
|
|
|
<p>
|
|
The aggregate functions shown below are available by default. Additional
|
|
aggregate functions written in C may be added using the
|
|
<a href="c3ref/create_function.html">sqlite3_create_function()</a>
|
|
API.</p>
|
|
|
|
<p>
|
|
In any aggregate function that takes a single argument, that argument
|
|
can be preceded by the keyword DISTINCT. In such cases, duplicate
|
|
elements are filtered before being passed into the aggregate function.
|
|
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.
|
|
</p>
|
|
|
|
<a name="aggfilter"></a>
|
|
|
|
<p>
|
|
If a FILTER clause is provided, then only rows for which the <i>expr</i> is
|
|
true are included in the aggregate.
|
|
</p>
|
|
|
|
<a name="aggfunclist"></a>
|
|
|
|
<h1 id="list_of_built_in_aggregate_functions"><span>2. </span>List of built-in aggregate functions</h1>
|
|
|
|
<div class='columns' style='columns: 11em auto;'>
|
|
<ul style='padding-top:0;'>
|
|
<li><a href='lang_aggfunc.html#avg'>avg(X)</a></li>
|
|
<li><a href='lang_aggfunc.html#count'>count(*)</a></li>
|
|
<li><a href='lang_aggfunc.html#count'>count(X)</a></li>
|
|
<li><a href='lang_aggfunc.html#groupconcat'>group_concat(X)</a></li>
|
|
<li><a href='lang_aggfunc.html#groupconcat'>group_concat(X,Y)</a></li>
|
|
<li><a href='lang_corefunc.html#maxoreunc'>max(X)</a></li>
|
|
<li><a href='lang_corefunc.html#minoreunc'>min(X)</a></li>
|
|
<li><a href='lang_aggfunc.html#sumunc'>sum(X)</a></li>
|
|
<li><a href='lang_aggfunc.html#sumunc'>total(X)</a></li>
|
|
</ul>
|
|
</div>
|
|
|
|
|
|
<h1 id="descriptions_of_built_in_aggregate_functions"><span>3. </span>Descriptions of built-in aggregate functions</h1>
|
|
<dl>
|
|
|
|
<a name="avg"></a>
|
|
<dt><p><b>avg(<i>X</i>)</b></dt><dd><p>
|
|
The avg() function
|
|
returns the average value of all non-NULL <i>X</i> within a
|
|
group. String and BLOB values that do not look like numbers are
|
|
interpreted as 0.
|
|
The result of avg() is always a floating point value as long as
|
|
at there is at least one non-NULL input even if all
|
|
inputs are integers. The result of avg() is NULL if and only if
|
|
there are no non-NULL inputs.
|
|
</dd>
|
|
<a name="count"></a>
|
|
<dt><p><b>count(<i>X</i>)<br />count(*)</b></dt><dd><p>
|
|
The count(X) function returns
|
|
a count of the number of times
|
|
that <i>X</i> is not NULL in a group. The count(*) function
|
|
(with no arguments) returns the total number of rows in the group.
|
|
</dd>
|
|
<a name="groupconcat"></a>
|
|
<dt><p><b>group_concat(<i>X</i>)<br />group_concat(<i>X</i>,<i>Y</i>)</b></dt><dd><p>
|
|
The group_concat() function returns
|
|
a string which is the concatenation of
|
|
all non-NULL values of <i>X</i>. If parameter <i>Y</i> is present then
|
|
it is used as the separator
|
|
between instances of <i>X</i>. A comma (",") is used as the separator
|
|
if <i>Y</i> is omitted. The order of the concatenated elements is
|
|
arbitrary.
|
|
</dd>
|
|
<a name="maxggunc"></a>
|
|
<dt><p><b>max(<i>X</i>)</b></dt><dd><p>
|
|
The max() aggregate function
|
|
returns the maximum value of all values in the group.
|
|
The maximum value is the value that would be returned last in an
|
|
ORDER BY on the same column. Aggregate max() returns NULL
|
|
if and only if there are no non-NULL values in the group.
|
|
</dd>
|
|
<a name="minggunc"></a>
|
|
<dt><p><b>min(<i>X</i>)</b></dt><dd><p>
|
|
The min() aggregate function
|
|
returns the minimum non-NULL value of all values in the group.
|
|
The minimum value is the first non-NULL value that would appear
|
|
in an ORDER BY of the column.
|
|
Aggregate min() returns NULL if and only if there are no non-NULL
|
|
values in the group.
|
|
</dd>
|
|
<a name="sumunc"></a>
|
|
<dt><p><b>sum(<i>X</i>)<br />total(<i>X</i>)</b></dt><dd><p>
|
|
The sum() and total() aggregate functions
|
|
return sum of all non-NULL values in the group.
|
|
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.</p>
|
|
|
|
<p>The result of total() is always a floating point value.
|
|
The result of sum() is an integer value if all non-NULL inputs are integers.
|
|
If any input to sum() is neither an integer or a NULL
|
|
then sum() returns a floating point value
|
|
which might be an approximation to the true sum.</p>
|
|
|
|
<p>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.
|
|
Total() never throws an integer overflow.
|
|
</dd>
|
|
|
|
</dl>
|
|
|