Tags

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


SQL Puzzle | The classic Multi-Column SEARCHING Puzzle | SQL Interview Question

In this puzzle you have to find out rows where we have pawan in any of the column. The restriction is that you cannot use the OR statement as we have N number of columns as it looks bad if we use some many columns with OR condition. For more details please see the sample input and expected output.

Sample Input

a b c d e f
Pawan P K Manmeet NULL Avtaar
A Avtaar Pawan NULL Sharlee NULL
NULL Pawan A Manmeet Sharlee Avtaar
Manmeet Pawan NULL Sharlee A Pawan
NULL Avtaar Z M Z K
NULL Pawan Q Manmeet T Sharlee
Manmeet T Avtaar NULL Sharlee Z

Expected Output

a b c d e f rnk
Pawan P K Manmeet NULL Avtaar 1
A Avtaar Pawan NULL Sharlee NULL 2
NULL Pawan A Manmeet Sharlee Avtaar 3
Manmeet Pawan NULL Sharlee A Pawan 4
NULL Pawan Q Manmeet T Sharlee 6

Script – DDL and INSERT Sample Data

--

CREATE TABLE TheMultiCheckingCondition 
(	
	  a VARCHAR(10)
	, b VARCHAR(10)
	, c VARCHAR(10)
	, d VARCHAR(10)
	, e VARCHAR(10)
	, f VARCHAR(10)

)
GO

INSERT INTO TheMultiCheckingCondition values 
('Pawan','P','K','Manmeet',NULL,'Avtaar'),
('A','Avtaar','Pawan',NULL,'Sharlee',NULL),
(NULL,'Pawan','A','Manmeet','Sharlee','Avtaar'),
('Manmeet','Pawan',NULL,'Sharlee','A','Pawan'),
(NULL,'Avtaar','Z','M','Z','K'),
(NULL,'Pawan','Q','Manmeet','T','Sharlee'),
('Manmeet','T','Avtaar',NULL,'Sharlee','Z')
GO

SELECT * FROM TheMultiCheckingCondition
GO


--

SOLUTION – 1

--

;WITH CTE AS
(
	SELECT *, ROW_NUMBER() OVER (Order by (SELECT NULL)) rnk
	FROM TheMultiCheckingCondition
)
SELECT c.* FROM CTE c
CROSS APPLY 
(
	SELECT * FROM CTE c1 WHERE c1.rnk = c.rnk 
	FOR XML RAW('w')
)z(t)
WHERE z.t LIKE '%pawan%'

--Note - Here I am using row_number column, normally you have Id column in your table. You need to use that column
--instead of row_number.

--

Output – 1

--

a          b          c          d          e          f          rnk
---------- ---------- ---------- ---------- ---------- ---------- --------------------
Pawan      P          K          Manmeet    NULL       Avtaar     1
A          Avtaar     Pawan      NULL       Sharlee    NULL       2
NULL       Pawan      A          Manmeet    Sharlee    Avtaar     3
Manmeet    Pawan      NULL       Sharlee    A          Pawan      4
NULL       Pawan      Q          Manmeet    T          Sharlee    6

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