Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2017 July SQL Puzzle: SQL Advance Query – Find third highest Employee Salary

SQL Puzzle: SQL Advance Query – Find third highest Employee Salary

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

Check below input/output data, and the employee third highest employee salary.

Input data:

1
2
3
4
5
6
7
8
9
10
empid ename salary
----------- ---------- -----------
1 pqr 25000
2 abc 25000
3 xyz 37000
4 pqr 35200
5 ymf 40000
6 sfs 40000
7 wer 37000
8 cvb 37800

Require output:

1
2
3
4
empid ename salary
----------- ---------- -----------
3 xyz 37000
7 wer 37000

Create a table with sample data:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
create table tbl_employee
(
empid int primary key
,ename varchar(10)
,salary int
)
GO
 
insert into tbl_employee values
(1,'pqr',25000)
,(2,'abc',25000)
,(3,'xyz',37000)
,(4,'pqr',35200)
,(5,'ymf',40000)
,(6,'sfs',40000)
,(7,'wer',37000)
,(8,'cvb',37800)
GO

Solution 1 (Correlated Subquery):

1
2
select * from tbl_employee as a
where 3 = (select count(distinct salary) from tbl_employee as b where a.salary<=b.salary)

Solution 2 (DENSE_RANK()):

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
with cteEmp as
(
select
empid
,ename
,salary
,DENSE_RANK() over (order by salary desc) as rnk
from tbl_employee
)
select
empid
,ename
,salary
from cteEmp
where rnk = 3

Solution 3 (MAX() & CROSS APPLY):

1
2
3
4
5
6
7
8
9
10
11
12
13
14
SELECT a.ename, b.salary
FROM
(
SELECT MAX(salary) Salary
FROM tbl_employee d
WHERE d.Salary !=
(
SELECT MAX(salary) Salary
FROM tbl_employee e
WHERE e.Salary != (SELECT MAX(salary) FROM tbl_employee)
)
and d.Salary != (SELECT MAX(salary) FROM tbl_employee)
) b
CROSS APPLY (SELECT ename FROM tbl_employee WHERE salary = b.salary ) a

Jul 19, 2017Anvesh Patel
SQL Server 2016: Use OPENJSON() to extract JSON data from Input ParameterSQL Puzzle: SQL Advance Query - Find a Book name which is printed in 50% of Languages

Leave a Reply Cancel reply

CAPTCHA
Refresh

*

Anvesh Patel
Anvesh Patel

Database Engineer

July 19, 2017 SQL PuzzleAnvesh Patel, Correlated Subquery, database, database research and development, dbrnd, SQL Advance Query, SQL Puzzle, SQL Query, SQL Server, SQL Server Administrator, SQL Server Error, SQL Server Monitoring, SQL Server Performance Tuning, SQL Server Programming, SQL Server Tips and Tricks, TSQL
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....