In the recent time of recession my company is able to continue its progress and we are hiring. It is very surprising to me that many developers who have experience with SQL Server could not get following simple question right. There were nearly 40 candidates I interviewed but none of the candidate was able to solve this problem. When I displayed final answer they could not believe that it is that simple.
When I asked some of the MCITP or Oracle certified candidate about why they can not get this simple question, they smiled and answered that I did not have that on my blog or on my interview questions list. Let us go over the interview question.
Let us create two tables. Once Created SELECT values from both the tables.
USE AdventureWorks
GO
/*Create First Table PersonColors*/
CREATEÂ TABLE PersonColors (Name VARCHAR(100), ColorCode VARCHAR(100))
GO
INSERTÂ INTO PersonColors (Name,ColorCode)
VALUES ('Tom','Red'),('Tom','Blue'),('Tom','Green'),('Tom','Brown'),
('Mike','Red'),('Mike','Blue'),
('James','Green'),('James','Brown'),
('Joe','Red'),('Joe','Blue'),('Joe','Green'),
('Matt','Brown')
GO
SELECT *
FROM PersonColors
GO
/*Create Second Table SelectedColors*/
CREATEÂ TABLE SelectedColors (ColorCode VARCHAR(100))
GO
INSERTÂ INTO SelectedColors (ColorCode)
VALUES ('Red'),('Blue'),('Green')
SELECT *
FROM SelectedColors
GO
The resultset of created table is as following.
Now the question is find all the persons from table PersonColor who have all the ColorCode mentioned in the table ColorCode. From the example it is clear that final result will contain Tom and Joe as answer. Tom has Red, Blue and Green as well Brown colorcode. If any person have Red, Blue and Green color they should qualify in our resultset. Joe has all the same colorcode as ColorCode table so it should also qualify in our resultset. Other person Mike and James did not have same kind of colorcode as table ColorCode.
In summary, Select all the person from table PersonColor who have same color as ColorCode or have more colors than table ColorCode.
When you look at this question it is very simple and answer is very simple as well. One of my employee was able to solve it in 3 mins. However, all the 40 interview candidates found it very difficult to write the query for the same.
Now before looking at the answer, please try to find the solution by yourself. Once you find the solution compare to the solution I have and see if you got it correct.
Expected Resultset should look like this.
Again, it may look very simple I would strongly suggest you try to solve it by yourself. If you can not solve it then try to look solution here.
UPDATE: I have used SQL Server 2008 script to generate the same table. I thank Tejas Shah for providing the script of SQL Server 2005 here.
Click here for Solution. (Go live on 12/11/2008)
Reference : Pinal Dave (https://blog.sqlauthority.com)
40 Comments. Leave new
I haven’t checked this but I reckon it would do the job:
select [name]
from
(select [name], count(colorcode) as c
from
(select *
from (select distinct * from personcolor) a
where [colorcode] in (select colorcode from selectedcolors)) b
group by [name]) d
where c = 3
Hey Dave.
Got an answer, same results..but can’t compare to your query, since the link does not work.
Is it supposed to go online tomorrow? Or is the link just wrong?
Good article.
select distinct name from PersonColors
where ColorCode in (select colorcode from SelectedColors)
group by name
having count(*) >=3
Hi Magesh, your code is OK but who knows the max count i.e 3, it may be 4 /5/6/7….. so i think btr is to put the sub-query for COUNT(ColorCode)
Thanks,
Subha
Pinal has provided script is for SQL 2008.
If you want to create with SQL server 2005. Use this one:
/*Create First Table PersonColors*/
CREATE TABLE PersonColors (Name VARCHAR(100), ColorCode VARCHAR(100))
GO
INSERT INTO PersonColors (Name,ColorCode)
SELECT’Tom’,’Red’
UNION ALL
SELECT
‘Tom’,’Green’
UNION ALL
SELECT
‘Tom’,’Brown’
UNION ALL
SELECT
‘Mike’,’Red’
UNION ALL
SELECT
‘Mike’,’Blue’
UNION ALL
SELECT
‘James’,’Green’
UNION ALL
SELECT
‘James’,’Brown’
UNION ALL
SELECT
‘Joe’,’Red’
UNION ALL
SELECT
‘Joe’,’Blue’
UNION ALL
SELECT
‘Joe’,’Green’
UNION ALL
SELECT
‘Matt’,’Brown’
GO
SELECT *
FROM PersonColors
GO
/*Create Second Table SelectedColors*/
CREATE TABLE SelectedColors (ColorCode VARCHAR(100))
GO
INSERT INTO SelectedColors (ColorCode)
SELECT ‘Red’
UNION ALL
SELECT ‘Blue’
UNION ALL
SELECT ‘Green’
GO
SELECT *
FROM SelectedColors
GO
Hi Pinal,
Please find the simplest way to fix it..It also takes care if ColorCodes table is Dynamic..so that I did this check HAVING COUNT(*) = (SELECT COUNT(*) FROM SelectedColors).
SELECT [Name]
FROM PersonColors pc
INNER JOIN SelectedColors sc ON pc.ColorCode = sc.ColorCode
GROUP BY [Name]
HAVING COUNT(*) = (SELECT COUNT(*) FROM SelectedColors)
Tejas
SELECT a.[Name]
FROM PersonColors a INNER JOIN SelectedColors b ON a.[ColorCode] = b.[ColorCode]
GROUP BY a.[Name]
HAVING COUNT(a.[Name]) > = (SELECT COUNT(a.[ColorCode]) FROM SelectedColors a)
SELECT [Name]
from SelectedColors p
left join PersonColors s on s.ColorCode = p.ColorCode
group by [Name]
having count(*) >= (select count(*) from SelectedColors )
Sorry. my answer is a dup of the query from Magesh and Tejas Shah. I am reading via RSS, so i am not the first. Please delete it if needed.
Hi Pinal,
I have tried this one and got the result also but i could not be able to compare with your solution as the link was not working.can pls tell me whether it is correct or not
Select distinct[name] from PersonColors
group by [name]
having count(colorcode)>=(select count(colorcode) from SelectedColors)
Hi Pinal,
Not sure about the optimization. But, I have this solution..
SELECT distinct NAME FROM PERSONCOLORS where colorcode in (select colorcode from selectedcolors) group by name
having COUNT(NAME)=(SELECT COUNT(*) FROM selectedcolors) . And this is my first reply to this blog as I am a front end developer, I am not much sure about the optimization. But Pival, your answer link doesn’t work for some reason. And I could not compare against your answer.
Hi,
It was really a good question. May be I have found the answer,
select [Name] from PersonColors
Group by [Name] having count(distinct(colorcode)) >= (
select count(distinct(ColorCode)) from SelectedColors)
Nice exercise Pinal :) Thanks :) It was quite simple and took me about 10 minutes. I don’t know how many minutes you give potential new employees ;)
I see everybody has the same solution.
Btw: I use Tejas Shah script to test on 2005 an there is ‘Tom’, ‘Blue’ record missed.
Good Question, the answer is
SELECT Name FROM PersonColors GROUP BY Name HAVING COUNT(ColorCode) >= (SELECT COUNT(*) FROM SelectedColors)
It gave the desired answer.
select distinct p.Name,count(p.Name)
from personcolors p
where exists (select * from selectedcolors sc where sc.colorcode=p.colorcode)
group by p.Name
having count(p.Name) = (select count(*) from selectedcolors )
The ones that use
COUNT(ColorCode) >= (SELECT COUNT(*) FROM SelectedColors)
are probably wrong. THe reason is because there is no validation to make sure that 3 of the COlorCodes that the person has are all in the SelectedColors table.
I mean, the results are coming up correct, but if you update the ColorCodes for the persons that have all three colors to have ColorCodes that are not in the SelectedColors table, the results will still show and one condition that Pinal specified was that they had to have all the colors in the other table.
again this is a good excercise.
The only drawback to Tejas’ solution is that you must ensure that duplicate entries in the PersonColor table are prevented.
See what happens if you add another row to the table with the values ‘Mike’, ‘Red’. Mike will now appear in the result query because his count is 3, even though he only has 2 colors.
To address that issue, this seemed to work:
SELECT [Name]
FROM
(select distinct [name],[colorcode] from PersonColors) pc
INNER JOIN SelectedColors sc ON pc.ColorCode = sc.ColorCode
GROUP BY [Name]
HAVING COUNT(*) = (SELECT COUNT(*) FROM SelectedColors)
Hi Pinal
I solved this problem within 5 mins.answer given below
select [Name] ,count(color_code) from
(select [name],color_main1.color_code from color_main inner join color_main1
on color_main.color_code=color_main1.color_code) cat1
group by [Name]
having count(color_code)=(select count(color_code) from color_main1)
Hi CB,
Thanks for this great solution.
I missed this situation, thanks for this solution. your solution is very correct.
Tejas
FYI – Tejas’s SQLSvr 2005 script left out a ‘Tom’, ‘Blue’.
For duplicate entries we just need to change the having clause in tejas’ query
HAVING COUNT(DISTINCT pc.ColorCode) >= (SELECT COUNT(ColorCode) FROM SelectedColors)