Tags
Advanced SQL Interview Questions and Answers, Advanced SQL tutorial pdf, any recommended websites for sql puzzles, Best SQL Puzzles, Buy SQL Server Interview Questions Book Online at Low Price, COmples tSQL puzzles, Complex SQL Challenges, complex sql statement(puzzle), Complex tsql, Complex TSQL Challenge, convert string to proper case in sql server, Divide rows into two columns, Download SQL Questions, Download SQL Server Interview Question in PDF, Download SQL SERVER Interview questions, Download SQL Server Interview questions and answers, download sql server interview questions and answers pdf, download sql server interview questions by Pawan Khowal, download sql server interview questions by Pawan Kumar, download sql server interview questions by Pawan Kumar Khowal, Download T-SQL Interview Questions, Free Download SQL SERVER Interview questions, Get Next Value Puzzle, Huge blank areas in database field, Improve SQL Skills, Interview Puzzles in SQL Server, Interview Qs.SQL SERVER Questions, Interview questions and Answers for MS SQL Server designing, Interview Questions and Answers For SQL, Interview questions on Joins, Interview Questions on SQL, Interview SQL Puzzles, InterviewQuestions, InterviewQuestions for SQL, Learn complex SQL, Learn SQL, Learn T-SQL, Microsoft SQL Server interview questions for DBA, MS SQL Server interview questions, MSBI Interview Questions, Objective Puzzle, Pawan, Pawan Khowal, Pawan Kumar, Pawan Kumar Khowal, PL/SQL Challenges, Puzzle SQL, puzzle sql developer, Puzzle SQl Server, Puzzles, PUzzles in SQL SERVER, Queries for SQL Interview, Remove Huge Multiple Spaces from a DB Fields, Remove Multiple Spaces from a DB Fields, Separate Int and char from a string column, Single Quote update SQL, SQL, SQL - The Pattern Puzzles, SQL 2012, SQL 2014, SQL 2014 Interview Questions, SQL Challenge, SQL Challenges, SQL Extreme Difficult Puzzle, SQL FAQ, SQL FAQs, sql group by only rows which are in sequence, SQL Interview Q & A, SQL Interview Questions, SQL Interview Questions - Part 2, SQL Interview Questions for SQL Professionals, SQL Joins, SQL Pattern Puzzles, SQL pl/sql puzzles, SQL prime number puzzle, SQL puzzle, SQL PUZZLE | Remove ALL if Others are Present Puzzle | SQL Interview Question, SQL Puzzles, sql puzzles & answers, sql puzzles and answers free download, sql puzzles and answers pdf, sql puzzles for interview, sql puzzles oracle, SQL Queries, SQL Queries asked in interviews, SQL QUERY PUZZLES, SQL Query to Find Nth Highest Salary of Employee, SQL Questions, SQL Quiz, SQL Replace Puzzle, SQL Server - Common Interview Questions and Answers, SQL SERVER - Find Nth Highest Salary of Employee, SQL Server - General Interview Questions and Answers, sql server 2008 interview questions, SQL Server 2008 Interview Questions and Answers, SQL Server Database, SQL Server database developer interview questions and answers, sql server dba interview questions, SQL Server developer Interview questions and answers, SQL Server developer Interview questions with answers, SQL Server Developer T-SQL Interview Questions, SQL server filter index with LIKE and RIGHT function?, SQL Server Interview Puzzle, SQL SERVER Interview questions, SQL SERVER Interview questions & Answers, SQL Server Interview Questions - Part 1, SQL Server Interview questions and answers, SQL Server Interview Questions and Answers - Free PDF, SQL SERVER Interview questions and answers for experienced, sql server interview questions and answers for net developers, SQL Server Interview Questions And Answers.pdf, sql server interview questions by Pawan Khowal sql interview questions, SQL SERVER Interview questions pdf, SQL Server Interview Questions | MSBISKILLS.Com, SQL Server Interview Questions | MSBISKILLS.com Top 50 SQL Server Questions & Answers, SQL Server Interview Questions/Answers Part-1, SQL Server Puzzle, SQL SERVER Puzzles, SQL server Questions and Answers, SQL SERVER Tips, SQL Skills, SQL Sudoku, SQL Tips & Tricks, SQL Tips and Tricks, SQL Top clause, SQL Tough Puzzle, SQL Tricks, SQL Trikcy question, sql/database interview for puzzle sql developer, SQLBI Interview Questions, SQLSERVER, SUM of grouped COUNT in SQL Query, T SQL Puzzles, T-SQL Challenge, T-SQL Interview Questions | SQL Server Interviews and Jobs, T-SQL Puzzle, T-SQL Server Interview Questions, T-SQL Tricky Puzzles, The Status Puzzle, Top 10 Frequently Asked SQL Query Interview Questions, TOP 100 SQL SERVER INTERVIEW QUESTIONS QUERIES, Top 50 SQL Server Interview Question for Testers, Tough SQL Challenges, Tough SQL Puzzles, Tricky Questions, TSQL, TSQL Challenge, TSQL Challenges, TSQL Interview questions, TSQL Puzzle, TSQL Puzzles, TSQL Queries
SQL PUZZLE | Remove ALL if Others are Present Puzzle | SQL Interview Question
In this puzzle you have to get rows with the following conditions-
1 : If any Id has 1 row with All in the dat column that row should come.
2 : If any Id has multiple rows and one of the row has All in the dat column then the row with the All column should not come.
For more details please refer sample input and expected output.
Sample Input
Id | Val | Dat |
---|---|---|
1 | a | Simple |
1 | a | All |
1 | a | Double |
2 | b | Triple |
2 | b | All |
3 | c | All |
3 | c | Simple |
3 | c | Double |
4 | e | All |
5 | f | All |
Expected output
Id | Val | Dat |
---|---|---|
1 | a | Simple |
1 | a | Double |
2 | b | Triple |
3 | c | Simple |
3 | c | Double |
4 | e | All |
5 | f | All |
Script – DDL and INSERT sample data
-- CREATE TABLE MyData ( Id INT ,Val VARCHAR(10) ,Dat VARCHAR(20) ) GO INSERT INTO MyData VALUES (1,'a','Simple'), (1,'a','All'), (1,'a','Double'), (2,'b','Triple'), (2,'b','All'), (3,'c','All'), (3,'c','Simple'), (3,'c','Double'), (4,'e','All'), (5,'f','All') GO SELECT * FROM MyData GO -- |
SOLUTION 1 – USING PARTITION COUNT, CASE and CASE
-- SELECT Id,Val,Dat FROM ( SELECT * , COUNT(1) OVER (PARTITION BY Id ORDER BY Id) a , CASE WHEN Dat = 'All' THEN 1 ELSE 0 END b FROM MyData )k WHERE 1 = CASE WHEN a = 1 AND b = 1 THEN 1 WHEN a > 1 AND b = 0 THEN 1 ELSE 0 END GO -- |
OUTPUT 1
-- Id Val Dat ----------- ---------- -------------------- 1 a Simple 1 a Double 2 b Triple 3 c Simple 3 c Double 4 e All 5 f All (7 rows affected) -- |
SOLUTION 2 – USING PARTITION COUNT, CASE and OR
-- SELECT Id,Val,Dat FROM ( SELECT * , COUNT(1) OVER (PARTITION BY Id ORDER BY Id) a , CASE WHEN Dat = 'All' THEN 1 ELSE 0 END b FROM MyData )k WHERE k.a = 1 OR ( k.b = 0 AND k.a > 1 ) GO -- |
OUTPUT 2
-- Id Val Dat ----------- ---------- -------------------- 1 a Simple 1 a Double 2 b Triple 3 c Simple 3 c Double 4 e All 5 f All (7 rows affected) -- |
SOLUTION 3 – Using Outer Apply and ISNULL
-- SELECT k.Id,k.Val, ISNULL(n.Dat,'All') Dat FROM ( SELECT DISTINCT Id,Val FROM MyData )k OUTER APPLY ( SELECT Dat FROM MyData b WHERE Dat <> 'All' AND k.Id = b.Id AND b.Val = k.Val )n -- |
OUTPUT 3
-- Id Val Dat ----------- ---------- -------------------- 1 a Simple 1 a Double 2 b Triple 3 c Simple 3 c Double 4 e All 5 f All (7 rows affected) -- |
SOLUTION 4 – Using UNION ALL and COUNT
-- Select ID,Val,Dat FROM MyData Where Dat != 'All' UNION ALL SELECT ID,VAL,Max(dat) FROM MYData GROUP by ID,val having count(*) = 1 and MAX(dat) = 'All' -- |
OUTPUT 4
-- Id Val Dat ----------- ---------- -------------------- 1 a Simple 1 a Double 2 b Triple 3 c Simple 3 c Double 4 e All 5 f All (7 rows affected) -- |
Enjoy 🙂
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
;with cte
as
(
select ID,val,COUNT(dat) as cnt
from #MyData
group by id,Val
)
,cte2
as
(
select a.Id,a.Val,
case when cnt=1 and Dat=’All’ then dat
when cnt>1 and dat=’All’ then ‘null’
when cnt>1 and dat!=’All’ then dat
end as DAT
from cte a
join #MyData b
on a.Id=b.Id
)
select id,val,DAT
from cte2
where DAT != ‘null’
LikeLiked by 1 person