Tags

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


SQL PUZZLE | Count children for each node Puzzle | SQL Interview Question

In this puzzle you have to find count of children for every node in the tree. Please check out sample input and expected output.

Sample Input

Id PId
1 NULL
2 1
3 1
4 2
5 2
6 3
6 3
7 4
8 7

Expected output

Id PId Cnts
1 NULL 9
2 1 5
3 1 3
6 3 2
6 3 2
4 2 3
5 2 1
7 4 2
8 7 1

Script – DDL and INSERT sample data

--

CREATE TABLE MyTree 
(
	 Id INT
	,PId INT
)
GO

INSERT INTO MyTree VALUES
(1, NULL),
(2, 1),
(3, 1),
(4, 2),
(5, 2),
(6, 3),
(6, 3),
(7, 4),
(8, 7)
GO

SELECT * FROM MyTree
GO

--

SOLUTION 1

--

;WITH CTE AS
(
	SELECT Id,PId,CONCAT('/', CAST(Id AS VARCHAR(MAX)) , '/') Ids FROM MyTree 
	WHERE PId IS NULL
	UNION ALL
	SELECT m.Id,m.PId,CONCAT(Ids,m.Id,'/') Ids FROM MyTree m 
	INNER JOIN CTE a ON a.Id = m.PId
)
SELECT Id,PId , ( SELECT COUNT(*) FROM CTE b WHERE b.Ids LIKE a.Ids + '%') Cnts 
FROM CTE a

--

OUTPUT – 1

--

Id          PId         Cnts
----------- ----------- -----------
1           NULL        9
2           1           5
3           1           3
6           3           2
6           3           2
4           2           3
5           2           1
7           4           2
8           7           1

(9 rows affected)

--

SOLUTION -2

--

;WITH CTE AS
(
	SELECT Id,PId, CAST( CONCAT('/', Id , '/') AS VARCHAR(1000)) Ids FROM MyTree 
	WHERE PId IS NULL
	UNION ALL
	SELECT m.Id,m.PId,CAST( CONCAT(Ids,m.Id,'/') AS VARCHAR(1000)) Ids FROM MyTree m 
	INNER JOIN CTE a ON a.Id = m.PId
),
CTE1 AS
(
	SELECT Id,PId,hierarchyid::Parse(Ids) Ids 
	, ROW_NUMBER() OVER (PARTITION BY Id,PId ORDER BY Id,PId) rnk
	FROM 
	CTE
)
,CTE2 AS
(
	SELECT a.Id , a.PId ,  COUNT(*) Cnts
	FROM CTE1 a
	INNER JOIN CTE1 b ON b.Ids.IsDescendantOf(a.Ids) = 1
	WHERE a.rnk = 1
	GROUP BY a.Id , a.PId 
)
SELECT c.Id,c.PId,c2.Cnts
FROM CTE1 c
LEFT JOIN CTE2 c2 ON c.Id = c2.Id AND 
(c.PId = c2.PId OR (c.PId IS NULL AND c2.PId IS NULL))

--

OUTPUT – 2

--

Id          PId         Cnts
----------- ----------- -----------
1           NULL        9
2           1           5
3           1           3
6           3           2
6           3           2
4           2           3
5           2           1
7           4           2
8           7           1

(9 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