COUNT Function
An aggregate function that returns the number of rows, or the number of non-NULL rows.
Syntax:
COUNT([DISTINCT | ALL] expression) [OVER (analytic_clause)]
Depending on the argument, COUNT() considers rows that meet certain conditions:
- The notation COUNT(*) includes NULL values in the total.
- The notation COUNT(column_name) only considers rows where the column contains a non-NULL value.
- You can also combine COUNT with the DISTINCT operator to eliminate duplicates before counting, and to count the combinations of values across multiple columns.
When the query contains a GROUP BY clause, returns one value for each combination of grouping values.
Return type: BIGINT
Usage notes:
If you frequently run aggregate functions such as MIN(), MAX(), and COUNT(DISTINCT) on partition key columns, consider enabling the OPTIMIZE_PARTITION_KEY_SCANS query option, which optimizes such queries. This feature is available in CDH 5.7 / Impala 2.5 and higher. See OPTIMIZE_PARTITION_KEY_SCANS Query Option for the kinds of queries that this option applies to, and slight differences in how partitions are evaluated when this query option is enabled.
Complex type considerations:
To access a column with a complex type (ARRAY, STRUCT, or MAP) in an aggregation function, you unpack the individual elements using join notation in the query, and then apply the function to the final scalar item, field, key, or value at the bottom of any nested type hierarchy in the column. See Complex Types (CDH 5.5 or higher only) for details about using complex types in Impala.
describe region; +-------------+-------------------------+---------+ | name | type | comment | +-------------+-------------------------+---------+ | r_regionkey | smallint | | | r_name | string | | | r_comment | string | | | r_nations | array<struct< | | | | n_nationkey:smallint, | | | | n_name:string, | | | | n_comment:string | | | | >> | | +-------------+-------------------------+---------+ select r_name, r_nations.item.n_nationkey from region, region.r_nations as r_nations order by r_name, r_nations.item.n_nationkey; +-------------+------------------+ | r_name | item.n_nationkey | +-------------+------------------+ | AFRICA | 0 | | AFRICA | 5 | | AFRICA | 14 | | AFRICA | 15 | | AFRICA | 16 | | AMERICA | 1 | | AMERICA | 2 | | AMERICA | 3 | | AMERICA | 17 | | AMERICA | 24 | | ASIA | 8 | | ASIA | 9 | | ASIA | 12 | | ASIA | 18 | | ASIA | 21 | | EUROPE | 6 | | EUROPE | 7 | | EUROPE | 19 | | EUROPE | 22 | | EUROPE | 23 | | MIDDLE EAST | 4 | | MIDDLE EAST | 10 | | MIDDLE EAST | 11 | | MIDDLE EAST | 13 | | MIDDLE EAST | 20 | +-------------+------------------+ select r_name, count(r_nations.item.n_nationkey) as count, sum(r_nations.item.n_nationkey) as sum, avg(r_nations.item.n_nationkey) as avg, min(r_nations.item.n_name) as minimum, max(r_nations.item.n_name) as maximum, ndv(r_nations.item.n_nationkey) as distinct_vals from region, region.r_nations as r_nations group by r_name order by r_name; +-------------+-------+-----+------+-----------+----------------+---------------+ | r_name | count | sum | avg | minimum | maximum | distinct_vals | +-------------+-------+-----+------+-----------+----------------+---------------+ | AFRICA | 5 | 50 | 10 | ALGERIA | MOZAMBIQUE | 5 | | AMERICA | 5 | 47 | 9.4 | ARGENTINA | UNITED STATES | 5 | | ASIA | 5 | 68 | 13.6 | CHINA | VIETNAM | 5 | | EUROPE | 5 | 77 | 15.4 | FRANCE | UNITED KINGDOM | 5 | | MIDDLE EAST | 5 | 58 | 11.6 | EGYPT | SAUDI ARABIA | 5 | +-------------+-------+-----+------+-----------+----------------+---------------+
Examples:
-- How many rows total are in the table, regardless of NULL values? select count(*) from t1; -- How many rows are in the table with non-NULL values for a column? select count(c1) from t1; -- Count the rows that meet certain conditions. -- Again, * includes NULLs, so COUNT(*) might be greater than COUNT(col). select count(*) from t1 where x > 10; select count(c1) from t1 where x > 10; -- Can also be used in combination with DISTINCT and/or GROUP BY. -- Combine COUNT and DISTINCT to find the number of unique values. -- Must use column names rather than * with COUNT(DISTINCT ...) syntax. -- Rows with NULL values are not counted. select count(distinct c1) from t1; -- Rows with a NULL value in _either_ column are not counted. select count(distinct c1, c2) from t1; -- Return more than one result. select month, year, count(distinct visitor_id) from web_stats group by month, year;
select x, property, count(x) over (partition by property) as count from int_t where property in ('odd','even'); +----+----------+-------+ | x | property | count | +----+----------+-------+ | 2 | even | 5 | | 4 | even | 5 | | 6 | even | 5 | | 8 | even | 5 | | 10 | even | 5 | | 1 | odd | 5 | | 3 | odd | 5 | | 5 | odd | 5 | | 7 | odd | 5 | | 9 | odd | 5 | +----+----------+-------+Adding an ORDER BY clause lets you experiment with results that are cumulative or apply to a moving set of rows (the "window"). The following examples use COUNT() in an analytic context (that is, with an OVER() clause) to produce a running count of all the even values, then a running count of all the odd values. The basic ORDER BY x clause implicitly activates a window clause of RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW, which is effectively the same as ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW, therefore all of these examples produce the same results:
select x, property, count(x) over (partition by property order by x) as 'cumulative count' from int_t where property in ('odd','even'); +----+----------+------------------+ | x | property | cumulative count | +----+----------+------------------+ | 2 | even | 1 | | 4 | even | 2 | | 6 | even | 3 | | 8 | even | 4 | | 10 | even | 5 | | 1 | odd | 1 | | 3 | odd | 2 | | 5 | odd | 3 | | 7 | odd | 4 | | 9 | odd | 5 | +----+----------+------------------+ select x, property, count(x) over ( partition by property order by x range between unbounded preceding and current row ) as 'cumulative total' from int_t where property in ('odd','even'); +----+----------+------------------+ | x | property | cumulative count | +----+----------+------------------+ | 2 | even | 1 | | 4 | even | 2 | | 6 | even | 3 | | 8 | even | 4 | | 10 | even | 5 | | 1 | odd | 1 | | 3 | odd | 2 | | 5 | odd | 3 | | 7 | odd | 4 | | 9 | odd | 5 | +----+----------+------------------+ select x, property, count(x) over ( partition by property order by x rows between unbounded preceding and current row ) as 'cumulative total' from int_t where property in ('odd','even'); +----+----------+------------------+ | x | property | cumulative count | +----+----------+------------------+ | 2 | even | 1 | | 4 | even | 2 | | 6 | even | 3 | | 8 | even | 4 | | 10 | even | 5 | | 1 | odd | 1 | | 3 | odd | 2 | | 5 | odd | 3 | | 7 | odd | 4 | | 9 | odd | 5 | +----+----------+------------------+The following examples show how to construct a moving window, with a running count taking into account 1 row before and 1 row after the current row, within the same partition (all the even values or all the odd values). Therefore, the count is consistently 3 for rows in the middle of the window, and 2 for rows near the ends of the window, where there is no preceding or no following row in the partition. Because of a restriction in the Impala RANGE syntax, this type of moving window is possible with the ROWS BETWEEN clause but not the RANGE BETWEEN clause:
select x, property, count(x) over ( partition by property order by x rows between 1 preceding and 1 following ) as 'moving total' from int_t where property in ('odd','even'); +----+----------+--------------+ | x | property | moving total | +----+----------+--------------+ | 2 | even | 2 | | 4 | even | 3 | | 6 | even | 3 | | 8 | even | 3 | | 10 | even | 2 | | 1 | odd | 2 | | 3 | odd | 3 | | 5 | odd | 3 | | 7 | odd | 3 | | 9 | odd | 2 | +----+----------+--------------+ -- Doesn't work because of syntax restriction on RANGE clause. select x, property, count(x) over ( partition by property order by x range between 1 preceding and 1 following ) as 'moving total' from int_t where property in ('odd','even'); ERROR: AnalysisException: RANGE is only supported with both the lower and upper bounds UNBOUNDED or one UNBOUNDED and the other CURRENT ROW.
Related information: