Ask the Expert

Only one distinct value in a group

I want to select rows from a table where ALL the values for a column are the same. For example, these two tables:

T1            T2
Num Let       Num Val
 1   A         1   R
 2   A         2   R
 3   C         3   S
 4   C         3   S
 5   D         3   -
 6   A         4   S
 7   A         4   S
 8   A         5   R

I want a query that will return all Num where T1.Num = T2.Num and ALL values for T2.Val are 'S'. The query should return:

Num
-----
4

The reason 3 is not returned is because at least one T2.Val is NOT an 'S'. Thanks if you can answer this.


    Requires Free Membership to View

Seems pretty straightforward. Try this:

select T2.Num
  from T1
inner
  join T2
    on T1.Num = T2.Num
group 
    by T2.Num
having count(distinct T2.Val) = 1
   and min(T2.Val) = 'S'

Since each row of T1 can join to more than one row of T2, a GROUP BY on T2.Num is required. The HAVING clause ensures that any T2.num is returned only when there's exactly one distinct T2.Val value in its group, and this value is 'S'. The MIN function is used, but it could also have been MAX, since there would be only one distinct value.

Note that a WHERE clause to restrict T2 rows to those containing 'S' would be wrong, unless accompanied by a NOT EXISTS correlated subquery to check for any other rows with any other value besides 'S' -- but this would be needlessly complex, so I won't show it.

UPDATE: Reader B. Humphreys emailed me with a concern about the solution above:

My understanding was that "Count(FieldName)" returned a count of NON-NULL values for the captioned field while "Count(*)" returned a count of all records (NULL or not).

If that's the case, will this actually work properly or will it return TRUE even though the field "T2.Val" contains NULLs in addition to one other non-NULL value?

An excellent observation. One way around this is to replace any NULLS with an empty string, and if there are only NULLs, then the MIN() condition would not be 'S':

select
 ...
having count(distinct coalesce(T2.Val,'')) = 1
   and min(T2.Val) = 'S'

Mr. Humphreys suggested:

select 
 ...
having count(T2.Val) = count(*)
   and min(T2.Val) = 'S'
   and max(T2.Val) = 'S'

This works perfectly, even in Microsoft Access (which does not support COUNT DISTINCT, at least not in the version I'm using). Thanks, B. Humphreys!


This was first published in December 2003

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to: