Q
Problem solve Get help with specific problems with your technologies, process and projects.

Detail rows for accounts that occur three times

Our SQL expert answers a tough query using both the IN subquery and derived tables.

I have a table with weekly data:
    WeekEnding   Amt   Acct
    ----------  ----   ----
    2007-10-06  5.00   XYZ
    2007-10-13  3.00   XYZ
    2007-10-20  0.23   XYZ
    2007-10-06  5.00   ZZZ
    2007-10-13  0.23   ZZZ
I want all of the accounts and amounts for accounts that occur in at least three different week ending dates. Can you help?

The difficulty with this type of problem is that it requires returning detail rows for a situation which is easily...

solved with HAVING. However, to use HAVING we have to use GROUP BY, and then the detail rows are aggregated. The way to approach this problem is to break it down into components. The first component of the solution does involve the HAVING clause.

select Acct 
  from Weekly
group
    by Acct
having count(*) >= 3

Note that COUNT(DISTINCT WeekEnding) also works. Whether we use this or the simpler COUNT(*) depends on whether the combination of WeekEnding and Acct is unique. Counting distinct values may be necessary if, for example, there are other columns you didn't mention, such as customer. In that case, we might have one row per customer per account per week ending date, so COUNT(DISTINCT WeekEnding) is necessary if the GROUP BY is only on the account.

Now that we know which accounts qualify, we can build the other component, which is the selection of all detail rows for the accounts which qualify. This can be accomplished in two ways. The first method uses an IN subquery:

select WeekEnding
     , Amt
     , Acct 
  from Weekly
 where Acct in
       ( select Acct 
           from Weekly
         group
             by Acct
         having count(*) >= 3 )

The second method uses the same subquery but as a derived table in the FROM clause:

select WeekEnding
     , Amt
     , Acct 
  from Weekly
inner
  join ( select Acct 
           from Weekly
         group
             by Acct
         having count(*) >= 3 ) as ok_accts
    on ok_accts.Acct = Weekly.Acct

What is the difference between these two solutions? As far as execution goes, they should perform the same. But the derived table has an advantage. Suppose that if, instead of one column, the HAVING condition needed to be based on a GROUP BY involving two columns. What if you wanted details for all customer accounts that occurred at least 3 times?

The first solution would be:

select WeekEnding
     , Amt
     , Acct 
     , Customer
  from Weekly
 where ( Acct, Customer ) in
       ( select Acct 
              , Customer
           from Weekly
         group
             by Acct
              , Customer
         having count(*) >= 3 )

This solution now uses what is called a row constructor, and this is perfectly valid SQL. The problem with row constructors is that not every database engine supports them. Yet.

Now imagine what the query involving the join to the derived table would look like.

This was last published in December 2007

Dig Deeper on Oracle and SQL

PRO+

Content

Find more PRO+ content and other member only offers, here.

Have a question for an expert?

Please add a title for your question

Get answers from a TechTarget expert on whatever's puzzling you.

You will be able to add details on the next page.

Start the conversation

Send me notifications when other members comment.

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

Please create a username to comment.

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close