Tags

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


SQL PUZZLE | The JOIN Puzzle | Advanced SQL

In this puzzle you to make some JOIN calculations and provide us the necessary output. For more details please see the sample input and expected output.

Sample Input

Table A

Id Vals
a 1
b 2

Table B

Id Valsa valsb
101 a 1
101 c 1
101 e 1
102 a 1
102 b 1
103 b 1
103 e 1
103 f 1

Expected Output

FirstId Vals SecId Id Valsa valsb
a 1 101 101 a 1
b 2 101 NULL NULL NULL
a 1 102 102 a 1
b 2 102 102 b 1
a 1 103 NULL NULL NULL
b 2 103 103 b 1

Script – DDL and INSERT Sample Data

--

CREATE TABLE FirstT
(
   Id VARCHAR(1)
  ,Vals INT
)
GO

INSERT INTO FirstT VALUES
('a', 1),
('b', 2)
GO

CREATE TABLE SecondT
(
    Id INT
   ,Valsa VARCHAR(1)
   ,valsb INT
)
GO

INSERT INTO SecondT VALUES
(101, 'a', 1),
(101, 'c', 1),
(101, 'e', 1),
(102, 'a', 1),
(102, 'b', 1),
(103, 'b', 1),
(103, 'e', 1),
(103, 'f', 1)
GO

SELECT * FROM FirstT
GO

SELECT * FROM SecondT
GO

--

SOLUTION – 1

--

;WITH CTE AS
(
	SELECT Id FirstId, Vals , SecId FROM FirstT
	,
	(
		SELECT Id SecId FROM SecondT GROUP BY Id
	)x
)
SELECT * FROM CTE C
LEFT JOIN SecondT T 
ON T.Id = C.SecId AND T.Valsa = C.FirstId

--

Output – 1

--

FirstId Vals        SecId       Id          Valsa valsb
------- ----------- ----------- ----------- ----- -----------
a       1           101         101         a     1
b       2           101         NULL        NULL  NULL
a       1           102         102         a     1
b       2           102         102         b     1
a       1           103         NULL        NULL  NULL
b       2           103         103         b     1

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