Updated SQL Puzzle | The INNER JOIN – Two Rows PUZZLE | Solution without UNION/UNION All

This is something really interesting. Here you have to join these two tables and provide the resulted data but the matching rows into Multiple Rows. The Challenge here is to do this without using UNION/UNION ALL. Please check out the sample input and the expected output.

Sample Input

Table 1 –

Id Vals
1 Pawan
2 Sharlee
3 Harry

Table 2 –

Id Vals
1 Kumar
2 Diwan

Expected Output

Id Vals
1 Pawan
1 Kumar
2 Sharlee
2 Diwan

Script – DDL and INSERT Sample Data

--

CREATE TABLE T1N1
(
	 Id INT
	,Vals Varchar(10)
)
GO

INSERT INTO T1N1 VALUES
(1,'Pawan'),
(2,'Sharlee'),
(3,'Harry')
GO

CREATE TABLE T1N2
(
	 Id INT
	,Vals Varchar(10)
)
GO

INSERT INTO T1N2 VALUES
(1,'Kumar'),
(2,'Diwan')
GO

SELECT * FROM T1N1
GO
SELECT * FROM T1N2
GO


--

SOLUTION 1

--

SELECT Id,Vals FROM 
(
	SELECT ISNULL(a.Id,B.Id) Id, ISNULL(a.Vals,B.Vals) Vals , COUNT(*) OVER (PARTITION BY ISNULL(a.Id,B.Id)) cnt
	FROM T1N1 a
	FULL OUTER JOIN T1N2 b ON a.Id = B.Id and a.Vals = b.Vals
)z WHERE cnt > 1

--

OUTPUT – 1

--

Id          Vals
----------- ----------
1           Pawan
1           Kumar
2           Diwan
2           Sharlee

(4 row(s) 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

Advertisements