Tags

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


SQL Puzzle | The Without OR Puzzle | SQL Interview Question

In this puzzle you have to find out rows where we have Pune in any of the column. The restriction is that you cannot use the OR statement. For more details please see the sample input and expected output.

Sample Input

a b c d
NULL Pune Nasik NULL
Nagar NULL Mumbai Lonavala
Pune Nagar Nagpur Lonavala
Pune Nagar Nagpur NULL

Expected Output

a b c d
NULL Pune Nasik NULL
Pune Nagar Nagpur Lonavala
Pune Nagar Nagpur NULL

Script – DDL and INSERT Sample Data

--

CREATE TABLE WithoutOR 
(	
	  a VARCHAR(10)
	, b VARCHAR(10)
	, c VARCHAR(10)
	, d VARCHAR(10)
)
GO

INSERT INTO WithoutOR values 
(NULL, 'Pune', 'Nasik',Null),
('Nagar', NULL, 'Mumbai','Lonavala'),
('Pune', 'Nagar', 'Nagpur','Lonavala'),
('Pune', 'Nagar', 'Nagpur',NULL)
GO

SELECT * FROM WithoutOR
GO

--

SOLUTION – 1

--

SELECT * 
FROM WithoutOR x 
WHERE EXISTS 
(
	SELECT NULL FROM WithoutOR WHERE CONCAT(x.a,x.b,x.c,x.d) LIKE '%Pune%'
)

--

Output – 1

--

a          b          c          d
---------- ---------- ---------- ----------
NULL       Pune       Nasik      NULL
Pune       Nagar      Nagpur     Lonavala
Pune       Nagar      Nagpur     NULL

(3 rows affected)

--

SOLUTION – 2

--

SELECT * FROM WithoutOR 
WHERE CONCAT(a,b,c,d) LIKE '%Pune%'

--

Output – 2

--

a          b          c          d
---------- ---------- ---------- ----------
NULL       Pune       Nasik      NULL
Pune       Nagar      Nagpur     Lonavala
Pune       Nagar      Nagpur     NULL

(3 rows affected)

--

SOLUTION – 3

--

SELECT *
FROM WithoutOR t
WHERE EXISTS 
(
	SELECT NULL
	FROM 
	(
		VALUES (a),(b),(c),(d)
	) x(m)
	WHERE m = 'Pune'
)

--

Output – 3

--

a          b          c          d
---------- ---------- ---------- ----------
NULL       Pune       Nasik      NULL
Pune       Nagar      Nagpur     Lonavala
Pune       Nagar      Nagpur     NULL

(3 rows affected)

--

SOLUTION – 4

--

SELECT t.*
FROM WithoutOR t
CROSS APPLY
(
	SELECT COUNT(*) cnt
	FROM 
	(
		VALUES (a), (b), (c),(d)
	) x(m)
	WHERE m = 'Pune'
)x
WHERE x.cnt > 0

--

Output – 4

--

a          b          c          d
---------- ---------- ---------- ----------
NULL       Pune       Nasik      NULL
Pune       Nagar      Nagpur     Lonavala
Pune       Nagar      Nagpur     NULL

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