August 15, 2010 at 6:01 pm
I have the following issue to solve;
I have two tables, one called Application and one called Contacts. The Application table has a unique col called ApplNbr which relates to the Contacts table. I need to develop a sql query that counts the average total number of Contact records for each application.
On reflection, perhaps a better approach might be to total the Contact count for each application and then GROUP BY the Contact Count and count the number of applications for each Contact count i.e.
Contacts Applications
1 10 <---- ie 10 Applications have 1 contact
2 20 <---- ie 20 Applications have 2 contacts etc
How can I achieve this is TSQL? Any help would be appreciated.
Thanks, Phil
August 15, 2010 at 6:35 pm
Something like this should do the trick.
SELECT COUNT(dtCnts.*) As NbApplications, dtCnts.CntContacts FROM (
SELECT ApplNbr, COUNT(*) As CntContacts FROM dbo.Contacts GROUP BY ApplNbr
) dtCnts
August 15, 2010 at 6:51 pm
Thanks, but I am still getting issues. Can you break it down further? Sorry, I am a newby.
I am using the following;
SELECT (SELECT distinct COUNT(a.ApplNbr)as "Applications" FROM tApplication a ) as "Applications",(
SELECT distinct COUNT(c.IdentityNbr) as "Contact records" from tApplContact c, tApplication a where c.ApplNbr = a.ApplNbr ) as "Contacts"
but this just returns
Applications Contacts
30202 1254
I really need to acheive
Applications Contacts
10 2 -- 10 applications have 2 contacts
39 4 -- 39 aplications have 4 contacts
August 15, 2010 at 7:01 pm
With what you've got there is essentially select count(a.*), count(b*)
First, get the data back. My guess is you want something like:
select a.applno
from application a
inner join contacts c
on a.applno = c.applno
Then you would add in the aggregate, however I"m not sure what averate total is? You have a single count per contract, not an average. There would be an overall average, but how it there an average per contract?
August 15, 2010 at 7:15 pm
Hi,
Thanks Steve.
I've not explained this well. 🙂
Using the following returns what I want , however;
SELECT (SELECT distinct COUNT(a.ApplNbr)as "Applications" FROM tApplication a ) as "Applications",(
SELECT distinct COUNT(c.IdentityNbr) as "Contact records" from tApplContact c, tApplication a where c.ApplNbr = a.ApplNbr ) as "Contacts"
This just returns;
Applications ContactNumbers
206 13
I need the data grid to show the following;
Applications ContactNumbers
10 2 (10 of my apps have 2 contacts)
42 7 (42 of mu apps have 7 contacts)
66 1
88 3
August 15, 2010 at 7:56 pm
Done it 🙂 . However, please feel free to let me know if this syntax is considered bad practise in any way.
IF OBJECT_ID('vwAppCounter') IS NOT NULL
DROP VIEW vwAppCounter
GO
CREATE VIEW vwAppCounter
AS
SELECT ApplNbr, COUNT(*) As Client_Contacts FROM tApplContact GROUP BY ApplNbr
GO
SELECT DISTINCT Client_Contacts , COUNT(ApplNbr)AS "Application_Count" FROM vwAppCounter
GROUP BY Client_Contacts order by Client_Contacts
DROP VIEW vwAppCounter
returns;
Client_Contacts, Application_Count
1, 3324
2, 324
3, 62
4, 15
5, 4
6, 4
7, 1
8, 1
9, 2
11, 1
12, 2
21, 1
Thanks for your help guys.
Phil
August 15, 2010 at 8:11 pm
Do you need this in a View?
August 15, 2010 at 8:24 pm
Hi,
I guess this would be better if I didnt use a view, but is it possible?
Cheers, Phil
August 15, 2010 at 10:04 pm
Yes, it is. For example:
SELECT DISTINCT
w.Client_Contacts,
COUNT(w.ApplNbr) AS "Application_Count"
FROM (
SELECT ApplNbr,
COUNT(*) As Client_Contacts
FROM tApplContact
GROUP BY ApplNbr
) w
GROUP BY w.Client_Contacts
ORDER BY w.Client_Contacts
You'll notice how the query that constituted the view has been contained in the sub query named "w".
August 16, 2010 at 8:04 am
Honestly, this is a place I'd use a CTE since it's cleaner, IMHO, to read. And it's becoming a bit of a convention in code.
With W (applnbr, application_count)
as
(
SELECT ApplNbr,
COUNT(*) As Client_Contacts
FROM tApplContact
GROUP BY ApplNbr
)
SELECT DISTINCT
w.Client_Contacts,
COUNT(w.ApplNbr) AS "Application_Count"
FROM w
GROUP BY w.Client_Contacts
ORDER BY w.Client_Contacts
August 16, 2010 at 2:04 pm
Thanks, thats much better than using a view. 🙂
August 16, 2010 at 6:03 pm
/* Get count of contact by app */
with ContactsByApp as (
select ApplNbr , count(*) as ContactCount
from Contacts
group by ApplNbr
)
/* get count of applications by contact count */
select
count(*) as [Applications used by]
, ContactCount as [this many apps]
from ContactsByApp a
group by ContactCount
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply