Referencing other columns in queries using group by

SQL standards state that the group by must contain items from the select list. However, Transact-SQL allows you to specify any valid column name in either the group by or select list, whether they employ aggregates or not.

Through the following extensions, Sybase lifts restrictions on what you can include or omit in the select list of a query that includes group by.

A vector aggregate must be accompanied by a group by clause. The SQL standards require that the non-aggregate columns in the select list match the group by columns. However, the first bulleted item described above allows you to specify additional, extended columns in the select list of the query.

For example, many versions of SQL do not allow the inclusion of the extended title_id column in the select list, but it is legal in Transact-SQL:

select type, title_id, avg(price), avg(advance) 
from titles 
group by type 
type           title_id 
------------   --------    -----   ------- 
business       BU1032      13.73  6,281.25 
business       BU1111      13.73  6,281.25 
business       BU2075      13.73  6,281.25 
business       BU7832      13.73  6,281.25 
mod_cook       MC2222      11.49  7,500.00 
mod_cook       MC3021      11.49  7,500.00 
UNDECIDED      MC3026      NULL       NULL 
popular_comp   PC1035      21.48  7,500.00 
popular_comp   PC8888      21.48  7,500.00 
popular_comp   PC9999      21.48  7,500.00 
psychology     PS1372      13.50  4,255.00 
psychology     PS2091      13.50  4,255.00 
psychology     PS2106      13.50  4,255.00 
psychology     PS3333      13.50  4,255.00 
psychology     PS7777      13.50  4,255.00 
trad_cook      TC3218      15.96  6,333.33 
trad_cook      TC4203      15.96  6,333.33 
trad_cook      TC7777      15.96  6,333.33 
 
(18 rows affected)

The above example still aggregates the price and advance columns based on the type column, but its results also display the title_id for the books included in each group.

The second extension described above allows you to group columns that are not specified as columns in the select list of the query. These columns do not appear in the results, but the vector aggregates still compute their summary values. For example:

select state, count(au_id)
from authors
group by state, city
state
-----  --------
CA            2
CA            1
CA            5
CA            5
CA            2
CA            1
CA            1
CA            1
CA            1
IN            1
KS            1
MD            1
MI            1
OR            1
TN            1
UT            2
 
(16 rows affected)

This example groups the vector aggregate results by both state and city, even though it does not display which city belongs to each group. Therefore, results are potentially misleading.

You may think the following query should produce similar results to the previous query, since only the vector aggregate seems to tally the number of each city for each row:

select state, count(au_id)
from authors
group by city

However, its results are much different. By not using group by with both the state and city columns, the query tallies the number of each city, but it displays the tally for each row of that city in authors rather than grouping them into one result row per city.

 state
 ----- ----------- 
 CA              1 
 CA              5 
 CA              2 
 CA              1 
 CA              5 
 KS              1 
 CA              2 
 CA              2 
 CA              1 
 CA              1 
 TN              1 
 OR              1 
 CA              1 
 MI              1 
 IN              1 
 CA              5 
 CA              5 
 CA              5 
 MD              1 
 CA              2 
 CA              1 
 UT              2 
 UT              2 

(23 rows affected)

When you use the Transact-SQL extensions in complex queries that include the where clause or joins, the results may become even more difficult to understand. To avoid confusing or misleading results with group by, Sybase suggests that you use the fipsflagger option to identify queries that use Transact-SQL extensions. See “group by and SQL standards” for details.

For more information about Transact-SQL extensions to group by and how they work, see the Reference Manual.