Tags

, , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , , ,


SQL PUZZLE | The ONLY type PUZZLE – One of my BEST SQL Interview Question

This is one of my best interview question for 5 years plus experience people. In this you have to find out rows where for each Id you have only one type of Type that is 21. In the sample you should get 2 and 4 rows as output. Please see the sample input and expected output.

Sample Input

Id Type Vals
1 3 900.00
1 3 200.00
1 3 800.00
1 21 200.00
2 21 100.00
2 21 100.00
3 3 100.00
3 3 100.00
4 21 100.00

Expected Output

Id Type Vals
2 21 100.00
2 21 100.00
4 21 100.00

Script – DDL and INSERT Sample Data

--

CREATE TABLE OnlyOneType
(
	 Id INT
	,[Type] INT
	,Vals DECIMAL(10,2)
)
GO

INSERT INTO OnlyOneType VALUES
(1,3 ,900.00 ),
(1,3 ,200.00 ),
(1,3 ,800.00 ),
(1,21,200.00 ),
(2,21,100.00  ),
(2,21,100.00  ),
(3,3 ,100.00 ),
(3,3 ,100.00 ),
(4,21,100.00)
GO

SELECT * FROM OnlyOneType T
GO

--

SOLUTION – 1

--

SELECT * FROM OnlyOneType T
WHERE [Type] = 21
AND NOT EXISTS ( SELECT NULL FROM OnlyOneType T1 WHERE T1.Id = T.Id and T1.Type <> 21 )


--

Output – 1

--

Id          Type        Vals
----------- ----------- ---------------------------------------
2           21          100.00
2           21          100.00
4           21          100.00

(3 rows affected)

--

SOLUTION – 2

--

SELECT Id,Type,Vals
FROM 
(
	SELECT *
	, COUNT(*) OVER(PARTITION BY Id) a 
	, SUM(CASE WHEN [Type]=21 THEN 1 ELSE 0 END) OVER(PARTITION BY Id) b 
	FROM OnlyOneType T
)x WHERE a = b

--

Output – 2

--

Id          Type        Vals
----------- ----------- ---------------------------------------
2           21          100.00
2           21          100.00
4           21          100.00

(3 rows affected)

--

SOLUTION – 3

--

SELECT T.* FROM OnlyOneType T
JOIN
(
	SELECT ID from OnlyOneType 
	GROUP BY ID having COUNT(DIstinct type) = 1 AND MAX([type]) = 21 
)x ON x.Id = T.Id

--

Output – 3

--

Id          Type        Vals
----------- ----------- ---------------------------------------
2           21          100.00
2           21          100.00
4           21          100.00

(3 rows affected)

--

Enjoy 🙂

Please add comment(s) if you have one or multiple solutions in mind. Thank You.

Pawan Khowal

Pawan is a SQL Server Developer. If you need any help in writing code/puzzle or training please email at – pawankkmr”AT”gmail.com. Meanwhile please go throgh the top pages from his blog.

Page Detail URL
☛ SQL Advance Puzzles https://msbiskills.com/tsql-puzzles-asked-in-interview-over-the-years/
☛ SQL Tricky Queries https://msbiskills.com/sql-puzzles-finding-outputs/
☛ SQL Server Perfomance tuning Articles https://msbiskills.com/sql-performance-tuning/
☛ SQL Server Articles https://msbiskills.com/t-sql/
☛ SQL Interview Questions & Answers https://msbiskills.com/sql-server-interview-questions/

My SQL Groups on Facebook:

1. If you like this post, you may want to join my SQL SERVER Interview Puzzles/Interview Questions on Facebook: https://www.facebook.com/groups/1430882120556342/

2. If you like this post, you may want to join my SQL Server Puzzles on Facebook:
https://www.facebook.com/groups/206594023090781/

My SQL Page on Facebook:

2. For all the updates you may follow my page -> https://www.facebook.com/MSBISkillscom-1602779883299222/

Enjoy !!! Keep Learning

Http://MsbiSkills.com

Advertisements