Tags

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


SQL Puzzle | Ignore Records present between Vals 11 and Vals 12 | Advanced SQL

In this puzzle you have to ignore the rows which are present between 11 and 12. For example if 13 is present between them then you have to ignore that record while selecting the data. For more details please see the sample input and expected output.

Sample Input

Id Vals
1 11
2 13
3 12
4 13
5 11
6 12
7 13
8 13
9 11
10 13
11 13
12 13
13 12
14 13
15 11

Expected Output

Id Vals
1 11
3 12
4 13
5 11
6 12
7 13
8 13
9 11
13 12
14 13
15 11

Script – DDL and INSERT Sample Data

--

CREATE TABLE GetSequenceGaps 
(
	 Id INT
	,Vals int
)
GO

INSERT INTO GetSequenceGaps VALUES
 (1,11)
,(2,13)
,(3,12)
,(4,13)
,(5,11)
,(6,12)
,(7,13)
,(8,13)
,(9,11)
,(10,13)
,(11,13)
,(12,13)
,(13,12)
,(14,13)
,(15,11)
GO

SELECT * FROM GetSequenceGaps
GO

--

SOLUTION – 1

--

;WITH CTE AS
(
	SELECT
		Id starts,
		x.Ends
	FROM GetSequenceGaps a
	OUTER APPLY
	(
		SELECT TOP 1 Id Ends from GetSequenceGaps b 
		WHERE a.id < b.id and b.Vals = 12 
		ORDER BY b.Id 
	)x
	WHERE a.Vals = 11
)
SELECT a.*
FROM GetSequenceGaps a
FULL JOIN CTE c ON a.id > c.starts and a.id < c.Ends
WHERE c.starts IS NULL AND c.Ends IS NULL

--

Output – 1

--

Id          Vals
----------- -----------
1           11
3           12
4           13
5           11
6           12
7           13
8           13
9           11
13          12
14          13
15          11

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