Please start any new threads on our new site at https://forums.sqlteam.com. We've got lots of great SQL Server experts to answer whatever question you can come up with.

 All Forums
 General SQL Server Forums
 New to SQL Server Programming
 Count how many duplicate records, but complex.

Author  Topic 

Slipstream19
Starting Member

5 Posts

Posted - 2013-07-26 : 09:28:29
Hi everyone,

ok here is the situation, I have a Contact table with first name, last name and email address. Now we have a generic test@test.com email we use and I want to find out how many contacts with that email, have the same first and last name. Example:

First Name | Last Name | Email
Mark Simpson test@test.com
Mike Johnson test@test.com
Mark Simpson test@test.com
Sarah Anderson test@test.com
Sarah Anderson test@test.com

Now I want to find out how many have duplicate records. So in the above case I would want return a count if 4, that are duplicates.

All I have so far is select * from contact where email = 'test@test.com' order by lastname, firstname.

This is great for seeing them, but I have too many records to see where there are duplicates.

Any help would be appreciated.

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-26 : 09:50:49
[code]SELECT FirstName, LastName, Email
FROM contact
WHERE email = 'test@test.com'
GROUP BY FirstName, LastName, Email
HAVING COUNT(*) > 1;[/code]
Go to Top of Page

MuMu88
Aged Yak Warrior

549 Posts

Posted - 2013-07-26 : 09:54:13
OR this

[CODE]
DECLARE @Temp1 TABLE ([First Name] VARCHAR(10), [Last Name] VARCHAR(20), Email VARCHAR(20));
INSERT INTO @Temp1 VALUES
('Mark', 'Simpson', 'test@test.com'),
('Mike', 'Johnson', 'test@test.com'),
('Mark', 'Simpson', 'test@test.com'),
('Sarah', 'Anderson', 'test@test.com'),
('Jim', 'Simpson', 'test1@test.com'),
('Sarah', 'Anderson', 'test@test.com'),
('Joe', 'Simpson', 'test2@test.com'),
('Sophy', 'Anderson', 'test11@test.com'),
('James', 'Simpson', 'test11@test.com'),
('Jill', 'Anderson', 'test11@test.com');


WITH CTE AS
(SELECT Email, COUNT(1) CNT from @Temp1 GROUP BY Email)
SELECT ROW_NUMBER() OVER(PARTITION by A.Email order by [First Name], [LAST NAME]) as RowNum, [First Name], [Last Name], A.Email, CNT FROM @Temp1 A
INNER JOIN CTE T ON T.Email = A.Email;

[/CODE]
EDITED
Go to Top of Page

Slipstream19
Starting Member

5 Posts

Posted - 2013-07-26 : 10:00:37
quote:
Originally posted by James K

SELECT FirstName, LastName, Email
FROM contact
WHERE email = 'test@test.com'
GROUP BY FirstName, LastName, Email
HAVING COUNT(*) > 1;




This is working..kind of. It returns the first name, last name and email of the record. but it doesn't tell mw how manu duplicates there are of that. for example it might return:

John Dow test@test.com
Jim Smith test@test.com

But there might be 4 dups of the first and 2 of the second. I would like to know how many records total there are like this. What would be perfect would be to see this:

John Dow test@test.com 2
Jim smith test@test.com 4

then at the end a total: 6
Go to Top of Page

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-26 : 10:08:30
Use Mumu's query, or add another column to the query as shown below:
SELECT FirstName, LastName, Email, COUNT(*) AS DupCount
FROM contact
WHERE email = 'test@test.com'
GROUP BY FirstName, LastName, Email
HAVING COUNT(*) > 1;
Go to Top of Page

MuMu88
Aged Yak Warrior

549 Posts

Posted - 2013-07-26 : 10:10:41
[CODE]


WITH CTE AS
(SELECT Email, COUNT(1) CNT from @Temp1 GROUP BY Email),
CTE1 AS
(SELECT ROW_NUMBER() OVER(PARTITION by A.Email order by [First Name], [LAST NAME]) as RowNum, [First Name], [Last Name], A.Email, CNT FROM @Temp1 A
INNER JOIN CTE T ON T.Email = A.Email)
SELECT [First Name], [LAST NAME], Email, COUNT(*) as TotalCount
FROM CTE1
GROUP BY [First Name], [LAST NAME], Email
HAVING COUNT(1) > 1
ORDER BY Email

[/CODE]
Go to Top of Page

Slipstream19
Starting Member

5 Posts

Posted - 2013-07-26 : 10:10:49
quote:
Originally posted by James K

Use Mumu's query, or add another column to the query as shown below:
SELECT FirstName, LastName, Email, COUNT(*) AS DupCount
FROM contact
WHERE email = 'test@test.com'
GROUP BY FirstName, LastName, Email
HAVING COUNT(*) > 1;




Well yours is working great. all I am missing now is a global count of all the ducount column
Go to Top of Page

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-26 : 10:12:05
If you want a total count, change the GROUP BY clause to this
GROUP BY GROUPING SETS
((FirstName, LastName, Email),())
Go to Top of Page

Slipstream19
Starting Member

5 Posts

Posted - 2013-07-26 : 10:13:58
quote:
Originally posted by James K

If you want a total count, change the GROUP BY clause to this
GROUP BY GROUPING SETS
((FirstName, LastName, Email),())




Thanks for all the help! This forum is great!
Go to Top of Page

James K
Master Smack Fu Yak Hacker

3873 Posts

Posted - 2013-07-26 : 10:34:10
You are very welcome. Glad to help.
Go to Top of Page
   

- Advertisement -