Tags

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


SQL Puzzle | Ranking Puzzle – 1 | SQL Interview Question

In this puzzle you have to provide the ranking in a new column. The logic for the ranking is that whenever you have a value “Product” then you have to start the new number and all other below should follow the same rank. Please check out the sample input and the expected output.

Sample Input

ID Vals
1 Product
2 a
3 a
4 a
5 a
6 Product
7 b
8 b
9 Product
10 c

Expected Output

ID Vals x
1 Product 1
2 a 1
3 a 1
4 a 1
5 a 1
6 Product 2
7 b 2
8 b 2
9 Product 3
10 c 3

Script – DDL and INSERT Sample Data

--

CREATE TABLE RankingPuzzle
(
	 ID INT
	,Vals VARCHAR(10)
)
GO

INSERT INTO RankingPuzzle VALUES 
(1,'Product'),
(2,'a'),
(3,'a'),
(4,'a'),
(5,'a'),
(6,'Product'),
(7,'b'),
(8,'b'),
(9,'Product'),
(10,'c')
GO

SELECT * FROM RankingPuzzle a
GO

--

SOLUTION 1

--

SELECT * ,
			(
				SELECT COUNT(*) cnt
				FROM RankingPuzzle b
				WHERE B.ID <= a.Id AND b.Vals = 'Product'
			)x
FROM RankingPuzzle a

--

OUTPUT – 1

--

ID          Vals       cnt
----------- ---------- -----------
1           Product    1
2           a          1
3           a          1
4           a          1
5           a          1
6           Product    2
7           b          2
8           b          2
9           Product    3
10          c          3

(10 rows affected)


--

SOLUTION 2

--

SELECT *, 
	SUM(IIF(Vals = 'Product',1,0)) OVER (ORDER BY Id) cnt
FROM RankingPuzzle

--

OUTPUT – 2

--

ID          Vals       cnt
----------- ---------- -----------
1           Product    1
2           a          1
3           a          1
4           a          1
5           a          1
6           Product    2
7           b          2
8           b          2
9           Product    3
10          c          3

(10 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 Performance 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