Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations strongm on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Count distinct values on sevaral fields 1

Status
Not open for further replies.

graabein

Programmer
Oct 9, 2002
186
NO
Hi, I have a sort of stupid table structure on the project I inherited. It's a list of what work was performed that uses codes like this:

CustomerID | Date | Code1 | Code2 | Code3 | Code4

I want to know all work that was performed for a certain period and thus need to count the distinct codes on codes 1-4.

Say I have the test data:

1 | today | AA | AB | AC | Null
2 | today | AC | BB | Null | Null

I want to get the following:

AA | 1
AB | 1
AC | 2
BB | 1

The table is pretty huge so I need an effective query... Any hints?

[elephant2]
graabein
 
Code:
SELECT daCode
     , COUNT(*) AS daCount
  FROM ( SELECT Code1 AS daCode
           FROM daTable
          WHERE Code1 IS NOT NULL
         UNION ALL
         SELECT Code2 
           FROM daTable
          WHERE Code2 IS NOT NULL
         UNION ALL
         SELECT Code3 
           FROM daTable
          WHERE Code3 IS NOT NULL
         UNION ALL
         SELECT Code4 
           FROM daTable
          WHERE Code4 IS NOT NULL
       ) AS d
GROUP
    BY daCode
:)

r937.com | rudy.ca
Buy my new book Simply SQL from Amazon
 
I think I did it! Check this out:
Code:
select Work.Code, count(*) from (
select Code1 as Code from table1
union all
select Code2 as Code from table1
) as Work
where Work.Code is not null
group by Work.Code

What do you think?

[elephant2]
graabein
 
LOL nice coincidence! Thanks man.

[elephant2]
graabein
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top